#!/usr/bin/python # -*- coding: utf-8 -*- from asyncio import Lock from sqlite3 import connect, Error, IntegrityError import sys import time DBLOCK = Lock() class SQLite: 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)) SQLite.create_tables(db_file) SQLite.add_statistics(db_file) return db_file #from slixfeed.log import Logger #from slixfeed.utilities import DateAndTime, Url # DBLOCK = Lock() #logger = Logger(__name__) def create_connection(db_file): """ Create a database connection to the SQLite database specified by db_file. Parameters ---------- db_file : str Path to database file. Returns ------- conn : object Connection object or None. """ time_begin = time.time() function_name = sys._getframe().f_code.co_name # message_log = '{}' # logger.debug(message_log.format(function_name)) conn = None try: conn = connect(db_file) conn.execute("PRAGMA foreign_keys = ON") # return conn except Error as e: print(e) # logger.warning('Error creating a connection to database {}.'.format(db_file)) # logger.error(e) time_end = time.time() difference = time_end - time_begin if difference > 1: logger.warning('{} (time: {})'.format(function_name, difference)) return conn def create_tables(db_file): """ Create SQLite tables. Parameters ---------- db_file : str Path to database file. """ function_name = sys._getframe().f_code.co_name # logger.debug('{}: db_file: {}' # .format(function_name, db_file)) with SQLite.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 SQLite.create_connection(db_file) as conn: cur = conn.cursor() try: cur.execute(sql) except IntegrityError as e: print(e) async def associate_entries_tags_jids(db_file, entry): async with DBLOCK: with SQLite.create_connection(db_file) as conn: cur = conn.cursor() jid = entry['jid'] url_hash = entry['url_hash'] entry_id = SQLite.get_entry_id_by_url_hash(db_file, url_hash) jid_id = SQLite.get_jid_id_by_jid(db_file, jid) if entry_id: for tag in entry['tags']: tag_id = SQLite.get_tag_id_by_tag(db_file, tag) cet_id = SQLite.get_combination_id_by_entry_id_tag_id_jid_id(db_file, entry_id, tag_id, jid_id) if not cet_id: sql = ( """ INSERT INTO combination_entries_tags_jids ( entry_id, tag_id, jid_id) VALUES ( ?, ?, ?); """ ) par = (entry_id, tag_id, jid_id) try: cur.execute(sql, par) except IntegrityError as e: print('associate_entries_tags_jids') print(e) async def add_tags(db_file, entries): """ Batch insertion of tags. Parameters ---------- db_file : str Path to database file. entries : list Set of entries. Returns ------- None. """ function_name = sys._getframe().f_code.co_name # logger.debug('{}: db_file: {}' # .format(function_name, db_file)) async with DBLOCK: with SQLite.create_connection(db_file) as conn: cur = conn.cursor() for entry in entries: tags = entry['tags'] for tag in tags: # sql = ( # """ # INSERT OR IGNORE INTO main_tags(tag) VALUES (?); # """ # ) if not SQLite.get_tag_id_by_tag(db_file, tag): sql = ( """ INSERT INTO main_tags(tag) VALUES(?); """ ) par = (tag,) try: cur.execute(sql, par) except IntegrityError as e: print(e) async def add_new_entries(db_file, entries): """ Batch insert of new entries into table entries. Parameters ---------- db_file : str Path to database file. entries : list Set of entries. Returns ------- None. """ function_name = sys._getframe().f_code.co_name # logger.debug('{}: db_file: {}' # .format(function_name, db_file)) async with DBLOCK: with SQLite.create_connection(db_file) as conn: cur = conn.cursor() for entry in entries: url_hash = entry['url_hash'] url = entry['link'] title = entry['title'] summary = entry['summary'] jid = entry['jid'] date_first = entry['published'] date_last = entry['published'] # instances = entry['instances'] # Import entries jid_id = SQLite.get_jid_id_by_jid(db_file, jid) sql = ( """ INSERT INTO main_entries( url_hash, url, title, summary, jid_id, date_first, date_last) VALUES( ?, ?, ?, ?, ?, ?, ?); """ ) par = (url_hash, url, title, summary, jid_id, date_first, date_last) try: cur.execute(sql, par) except IntegrityError as e: print(e) print(jid_id) print(entry) # logger.warning("Skipping: " + str(url)) # logger.error(e) # TODO An additional function to ssociate jid_id (jid) with entry_id (hash_url) async def set_jid(db_file, jid): """ Add a JID to database. Parameters ---------- db_file : str Path to database file. jid : str A Jabber ID. Returns ------- None. """ function_name = sys._getframe().f_code.co_name # logger.debug('{}: db_file: {} jid: {}' # .format(function_name, db_file, jid)) sql = ( """ INSERT INTO main_jids( jid) VALUES( ?); """ ) par = (jid, ) async with DBLOCK: with SQLite.create_connection(db_file) as conn: cur = conn.cursor() try: cur.execute(sql, par) except IntegrityError as e: print(e) # logger.warning("Skipping: " + str(url)) # logger.error(e) def get_entries_count(db_file): """ Get entries count. Parameters ---------- db_file : str Path to database file. Returns ------- result : tuple Number. """ function_name = sys._getframe().f_code.co_name # logger.debug('{}: db_file: {}' # .format(function_name, db_file)) sql = ( """ SELECT count FROM main_statistics WHERE type = "entries"; """ ) with SQLite.create_connection(db_file) as conn: cur = conn.cursor() result = cur.execute(sql).fetchone() return result[0] if result and len(result) == 1 else result def get_combination_id_by_entry_id_tag_id_jid_id(db_file, entry_id, tag_id, jid_id): """ Get ID by a given Entry ID and a given Tag ID and a given Jabber ID. Parameters ---------- db_file : str Path to database file. entry_id : str Entry ID. tag_id : str Tag ID. jid_id : str Jabber ID. Returns ------- result : tuple ID. """ function_name = sys._getframe().f_code.co_name # logger.debug('{}: db_file: {} entry_id: {} tag_id: {} jid_id: {}' # .format(function_name, db_file, entry_id, tag_id, jid_id)) sql = ( """ SELECT id FROM combination_entries_tags_jids WHERE entry_id = :entry_id AND tag_id = :tag_id AND jid_id = :jid_id; """ ) par = { "entry_id": entry_id, "tag_id": tag_id, "jid_id": jid_id } with SQLite.create_connection(db_file) as conn: cur = conn.cursor() result = cur.execute(sql, par).fetchone() return result[0] if result and len(result) == 1 else result async def delete_combination_row_by_url_hash_and_tag_and_jid(db_file, url_hash, tags, jid): """ Delete a row by a given entry ID and a given Jabber ID and given tags. Parameters ---------- db_file : str Path to database file. url_hash : str URL hash. tags : list Tags. jid : str Jabber ID. Returns ------- None. """ function_name = sys._getframe().f_code.co_name # logger.debug('{}: db_file: {} url_hash: {} tag_id: {} jid_id: {}' # .format(function_name, db_file, url_hash, tag_id, jid_id)) sql = ( """ DELETE FROM combination_entries_tags_jids WHERE entry_id = (SELECT id FROM main_entries WHERE url_hash = :url_hash) AND tag_id = (SELECT id FROM main_tags WHERE tag = :tag) AND jid_id = (SELECT id FROM main_jids WHERE jid = :jid); """ ) async with DBLOCK: with SQLite.create_connection(db_file) as conn: for tag in tags: par = { "url_hash": url_hash, "tag": tag, "jid": jid } cur = conn.cursor() cur.execute(sql, par) def get_tag_id_and_instances_by_tag(db_file, tag): """ Get a tag ID and instances by a given tag. Parameters ---------- db_file : str Path to database file. tag : str Tag. Returns ------- result : tuple Tag ID. """ function_name = sys._getframe().f_code.co_name # logger.debug('{}: db_file: {} tag: {}' # .format(function_name, db_file, tag)) sql = ( """ SELECT id, instances FROM main_tags WHERE tag = ?; """ ) par = (tag,) with SQLite.create_connection(db_file) as conn: cur = conn.cursor() result = cur.execute(sql, par).fetchone() # return result[0] if result else None, None if not result: result = None, None return result def get_tags_and_instances_by_url_hash(db_file, url_hash): """ Get tags and instances by a given URL hash. Parameters ---------- db_file : str Path to database file. url_hash : str A hash of a URL. Returns ------- result : tuple Tags and instances. """ function_name = sys._getframe().f_code.co_name # logger.debug('{}: db_file: {} index_first: {}' # .format(function_name, db_file, index_first)) sql = ( """ SELECT mt.tag, mt.instances FROM main_tags AS mt INNER JOIN combination_entries_tags_jids AS co ON mt.id = co.tag_id INNER JOIN main_entries AS me ON me.id = co.entry_id WHERE me.url_hash = ? ORDER BY mt.instances DESC; """ ) par = (url_hash,) with SQLite.create_connection(db_file) as conn: cur = conn.cursor() result = cur.execute(sql, par).fetchall() return result def get_tags_and_instances_by_entry_id(db_file, entry_id): """ Get tags and instances by a given ID entry. Parameters ---------- db_file : str Path to database file. entry_id : str An ID of an entry. Returns ------- result : tuple Tags and instances. """ function_name = sys._getframe().f_code.co_name # logger.debug('{}: db_file: {} index_first: {}' # .format(function_name, db_file, index_first)) sql = ( """ SELECT main_tags.tag, main_tags.instances FROM main_tags INNER JOIN combination_entries_tags_jids ON main_tags.id = combination_entries_tags_jids.tag_id WHERE combination_entries_tags_jids.entry_id = ? ORDER BY main_tags.instances DESC; """ ) par = (entry_id,) with SQLite.create_connection(db_file) as conn: cur = conn.cursor() result = cur.execute(sql, par).fetchall() return result def get_jids_and_tags_by_entry_id(db_file, entry_id): """ Get JIDs and tags by a given ID entry. Parameters ---------- db_file : str Path to database file. entry_id : str An ID of an entry. Returns ------- result : tuple JIDs and tags. """ function_name = sys._getframe().f_code.co_name # logger.debug('{}: db_file: {} index_first: {}' # .format(function_name, db_file, index_first)) sql = ( """ SELECT main_jids.jid, main_tags.tag FROM main_tags INNER JOIN combination_entries_tags_jids ON main_tags.id = combination_entries_tags_jids.tag_id INNER JOIN main_jids ON main_jids.id = combination_entries_tags_jids.jid_id WHERE combination_entries_tags_jids.entry_id = ? ORDER BY main_tags.instances DESC; """ ) par = (entry_id,) with SQLite.create_connection(db_file) as conn: cur = conn.cursor() result = cur.execute(sql, par).fetchall() return result def get_jids_and_tags_by_url_hash(db_file, url_hash): """ Get JIDs and tags by a given URI hash. Parameters ---------- db_file : str Path to database file. url_hash : str A URL hash of an entry. Returns ------- result : tuple JIDs and tags. """ function_name = sys._getframe().f_code.co_name # logger.debug('{}: db_file: {} index_first: {}' # .format(function_name, db_file, index_first)) sql = ( """ SELECT main_jids.jid, main_tags.tag FROM main_tags INNER JOIN combination_entries_tags_jids ON main_tags.id = combination_entries_tags_jids.tag_id INNER JOIN main_jids ON main_jids.id = combination_entries_tags_jids.jid_id INNER JOIN main_entries ON main_entries.id = combination_entries_tags_jids.entry_id WHERE main_entries.url_hash = ? ORDER BY main_tags.instances DESC; """ ) par = (url_hash,) with SQLite.create_connection(db_file) as conn: cur = conn.cursor() result = cur.execute(sql, par).fetchall() return result def get_tag_id_by_tag(db_file, tag): """ Get a tag ID by a given tag. Parameters ---------- db_file : str Path to database file. tag : str Tag. Returns ------- result : tuple Tag ID. """ function_name = sys._getframe().f_code.co_name # logger.debug('{}: db_file: {} tag: {}' # .format(function_name, db_file, tag)) sql = ( """ SELECT id FROM main_tags WHERE tag = ?; """ ) par = (tag,) with SQLite.create_connection(db_file) as conn: cur = conn.cursor() result = cur.execute(sql, par).fetchone() return result[0] if result and len(result) == 1 else result def get_entry_id_by_url_hash(db_file, url_hash): """ Get an entry ID by a given URL hash. Parameters ---------- db_file : str Path to database file. url_hash : str MD5 hash of URL. Returns ------- result : tuple Entry ID. """ function_name = sys._getframe().f_code.co_name # logger.debug('{}: db_file: {} url_hash: {}' # .format(function_name, db_file, url_hash)) sql = ( """ SELECT id FROM main_entries WHERE url_hash = ?; """ ) par = (url_hash,) with SQLite.create_connection(db_file) as conn: cur = conn.cursor() result = cur.execute(sql, par).fetchone() return result[0] if result and len(result) == 1 else result def get_entry_instances_by_url_hash(db_file, url_hash): """ Get value of entry instances by a given URL hash. Parameters ---------- db_file : str Path to database file. url_hash : str MD5 hash of URL. Returns ------- result : tuple Value of entry instances. """ function_name = sys._getframe().f_code.co_name # logger.debug('{}: db_file: {} url_hash: {}' # .format(function_name, db_file, url_hash)) sql = ( """ SELECT instances FROM main_entries WHERE url_hash = ?; """ ) par = (url_hash,) with SQLite.create_connection(db_file) as conn: cur = conn.cursor() result = cur.execute(sql, par).fetchone() return result[0] if result and len(result) == 1 else result def get_entry_by_url_hash(db_file, url_hash): """ Get entry of a given URL hash. Parameters ---------- db_file : str Path to database file. url_hash : str MD5 hash of URL. Returns ------- result : tuple Entry properties. """ function_name = sys._getframe().f_code.co_name # logger.debug('{}: db_file: {} url_hash: {}' # .format(function_name, db_file, url_hash)) sql = ( """ SELECT * FROM main_entries WHERE url_hash = ?; """ ) par = (url_hash,) with SQLite.create_connection(db_file) as conn: cur = conn.cursor() result = cur.execute(sql, par).fetchone() return result[0] if result and len(result) == 1 else result def get_entries_new(db_file, index_first): """ Get new entries. Parameters ---------- db_file : str Path to database file. index_first : str . Returns ------- result : tuple Entries properties. """ function_name = sys._getframe().f_code.co_name # logger.debug('{}: db_file: {} index_first: {}' # .format(function_name, db_file, index_first)) # NOTE Consider date_first sql = ( """ SELECT * FROM main_entries ORDER BY date_first DESC LIMIT 10 OFFSET ?; """ ) par = (index_first,) with SQLite.create_connection(db_file) as conn: cur = conn.cursor() result = cur.execute(sql, par).fetchall() return result def get_entries_popular(db_file, index_first): """ Get popular entries. Parameters ---------- db_file : str Path to database file. index_first : str . Returns ------- result : tuple Entries properties. """ function_name = sys._getframe().f_code.co_name # logger.debug('{}: db_file: {} index_first: {}' # .format(function_name, db_file, index_first)) # NOTE Consider date_first sql = ( """ SELECT * FROM main_entries ORDER BY instances DESC LIMIT 10 OFFSET ?; """ ) par = (index_first,) with SQLite.create_connection(db_file) as conn: cur = conn.cursor() result = cur.execute(sql, par).fetchall() return result def get_entries_recent(db_file, index_first): """ Get recent entries. Parameters ---------- db_file : str Path to database file. index_first : str . Returns ------- result : tuple Entries properties. """ function_name = sys._getframe().f_code.co_name # logger.debug('{}: db_file: {} index_first: {}' # .format(function_name, db_file, index_first)) # NOTE Consider date_first sql = ( """ SELECT * FROM main_entries ORDER BY date_last DESC LIMIT 10 OFFSET ?; """ ) par = (index_first,) with SQLite.create_connection(db_file) as conn: cur = conn.cursor() result = cur.execute(sql, par).fetchall() return result def get_entries_by_query(db_file, query, index_first): """ Get entries by a query. Parameters ---------- db_file : str Path to database file. query : str Search query. index_first : str . Returns ------- result : tuple Entries properties. """ function_name = sys._getframe().f_code.co_name # logger.debug('{}: db_file: {} index_first: {}' # .format(function_name, db_file, index_first)) # NOTE Consider date_first sql = ( """ SELECT * FROM main_entries WHERE title LIKE :query OR url LIKE :query OR summary LIKE :query ORDER BY instances DESC LIMIT 10 OFFSET :index_first; """ ) par = { "query": f'%{query}%', "index_first": index_first } with SQLite.create_connection(db_file) as conn: cur = conn.cursor() result = cur.execute(sql, par).fetchall() return result def get_entries_count_by_query(db_file, query): """ Get entries count by a query. Parameters ---------- db_file : str Path to database file. query : str Search query. Returns ------- result : tuple Entries properties. """ function_name = sys._getframe().f_code.co_name # logger.debug('{}: db_file: {}' # .format(function_name, db_file)) # NOTE Consider date_first sql = ( """ SELECT COUNT(id) FROM main_entries WHERE title LIKE :query OR url LIKE :query OR summary LIKE :query ORDER BY instances DESC; """ ) par = { "query": f'%{query}%', } with SQLite.create_connection(db_file) as conn: cur = conn.cursor() result = cur.execute(sql, par).fetchone() return result[0] if result and len(result) == 1 else result def get_entries_by_jid_and_tag(db_file, jid, tag, index_first): """ Get entries by a tag and a Jabber ID. Parameters ---------- db_file : str Path to database file. tag : str Tag. jid : str Jabber ID. index_first : str . Returns ------- result : tuple Entries properties. """ function_name = sys._getframe().f_code.co_name # logger.debug('{}: db_file: {} tag: {} jid: {} index_first: {}' # .format(function_name, db_file, tag, jid, index_first)) # NOTE Consider date_first sql = ( """ SELECT DISTINCT me.* FROM main_entries AS me INNER JOIN combination_entries_tags_jids AS co ON co.entry_id = me.id INNER JOIN main_jids AS mj ON mj.id = co.jid_id INNER JOIN main_tags AS mt ON mt.id = co.tag_id WHERE mj.jid = :jid AND mt.tag = :tag ORDER BY instances DESC LIMIT 10 OFFSET :index_first; """ ) par = { "jid": jid, "tag": tag, "index_first": index_first } with SQLite.create_connection(db_file) as conn: cur = conn.cursor() result = cur.execute(sql, par).fetchall() return result def get_entries_count_by_jid_and_tag(db_file, jid, tag): """ Get entries count by a tag and a Jabber ID. Parameters ---------- db_file : str Path to database file. tag : str Tag. jid : str Jabber ID. Returns ------- result : tuple Entries properties. """ function_name = sys._getframe().f_code.co_name # logger.debug('{}: db_file: {} tag: {} jid: {}' # .format(function_name, db_file, tag, jid)) # NOTE Consider date_first sql = ( """ SELECT COUNT(DISTINCT me.id) FROM main_entries AS me INNER JOIN combination_entries_tags_jids AS co ON co.entry_id = me.id INNER JOIN main_jids AS mj ON mj.id = co.jid_id INNER JOIN main_tags AS mt ON mt.id = co.tag_id WHERE mj.jid = :jid AND mt.tag = :tag; """ ) par = { "jid": jid, "tag": tag } with SQLite.create_connection(db_file) as conn: cur = conn.cursor() result = cur.execute(sql, par).fetchone() return result[0] if result and len(result) == 1 else result def get_entries_by_jid_and_query(db_file, jid, query, index_first): """ Get entries by a query and a Jabber ID. Parameters ---------- db_file : str Path to database file. query : str Search query. jid : str Jabber ID. index_first : str . Returns ------- result : tuple Entries properties. """ function_name = sys._getframe().f_code.co_name # logger.debug('{}: db_file: {} query: {} jid: {} index_first: {}' # .format(function_name, db_file, query, jid, index_first)) # NOTE Consider date_first sql = ( """ SELECT DISTINCT me.* FROM main_entries AS me INNER JOIN combination_entries_tags_jids AS co ON co.entry_id = me.id INNER JOIN main_jids AS mj ON mj.id = co.jid_id WHERE mj.jid = :jid AND (title LIKE :query OR url LIKE :query OR summary LIKE :query) ORDER BY instances DESC LIMIT 10 OFFSET :index_first; """ ) par = { "jid": jid, "query": f'%{query}%', "index_first": index_first } with SQLite.create_connection(db_file) as conn: cur = conn.cursor() result = cur.execute(sql, par).fetchall() return result def get_entries_count_by_jid_and_query(db_file, jid, query): """ Get entries count by a query and a Jabber ID. Parameters ---------- db_file : str Path to database file. query : str Search query. jid : str Jabber ID. Returns ------- result : tuple Entries properties. """ function_name = sys._getframe().f_code.co_name # logger.debug('{}: db_file: {} query: {} jid: {}' # .format(function_name, db_file, query, jid)) # NOTE Consider date_first sql = ( """ SELECT COUNT(DISTINCT me.id) FROM main_entries AS me INNER JOIN combination_entries_tags_jids AS co ON co.entry_id = me.id INNER JOIN main_jids AS mj ON mj.id = co.jid_id WHERE mj.jid = :jid AND (title LIKE :query OR url LIKE :query OR summary LIKE :query); """ ) par = { "jid": jid, "query": f'%{query}%' } with SQLite.create_connection(db_file) as conn: cur = conn.cursor() result = cur.execute(sql, par).fetchone() return result[0] if result and len(result) == 1 else result def get_entries_by_jid(db_file, jid, index_first): """ Get entries by a Jabber ID. Parameters ---------- db_file : str Path to database file. jid : str Jabber ID. index_first : str . Returns ------- result : tuple Entries properties. """ function_name = sys._getframe().f_code.co_name # logger.debug('{}: db_file: {} jid: {} index_first: {}' # .format(function_name, db_file, jid, index_first)) # NOTE Consider date_first sql = ( """ SELECT DISTINCT me.* FROM main_entries AS me INNER JOIN combination_entries_tags_jids AS co ON co.entry_id = me.id INNER JOIN main_jids AS mj ON mj.id = co.jid_id WHERE mj.jid = :jid ORDER BY instances DESC LIMIT 10 OFFSET :index_first; """ ) par = { "jid": jid, "index_first": index_first } with SQLite.create_connection(db_file) as conn: cur = conn.cursor() result = cur.execute(sql, par).fetchall() return result def get_entries_count_by_jid(db_file, jid): """ Get entries count by a Jabber ID. Parameters ---------- db_file : str Path to database file. jid : str Jabber ID. Returns ------- result : tuple Entries properties. """ function_name = sys._getframe().f_code.co_name # logger.debug('{}: db_file: {} jid: {}' # .format(function_name, db_file, jid)) # NOTE Consider date_first sql = ( """ SELECT COUNT(DISTINCT me.id) FROM main_entries AS me INNER JOIN combination_entries_tags_jids AS co ON co.entry_id = me.id INNER JOIN main_jids AS mj ON mj.id = co.jid_id WHERE mj.jid = :jid; """ ) par = { "jid": jid } with SQLite.create_connection(db_file) as conn: cur = conn.cursor() result = cur.execute(sql, par).fetchone() return result[0] if result and len(result) == 1 else result def get_entries_count_by_tag(db_file, tag): """ Get entries count by a given tag. Parameters ---------- db_file : str Path to database file. tag : str A tag. Returns ------- result : tuple Entries. """ function_name = sys._getframe().f_code.co_name # logger.debug('{}: db_file: {} tag: {}' # .format(function_name, db_file, tag)) sql = ( """ SELECT COUNT(DISTINCT entries.id) FROM main_entries AS entries INNER JOIN combination_entries_tags_jids AS co ON entries.id = co.entry_id INNER JOIN main_tags AS tags ON tags.id = co.tag_id WHERE tags.tag = :tag; """ ) par = (tag,) with SQLite.create_connection(db_file) as conn: cur = conn.cursor() result = cur.execute(sql, par).fetchone() return result[0] if result and len(result) == 1 else result def get_entries_popular_by_tag(db_file, tag, index_first): """ Get popular entries by a given tag. Parameters ---------- db_file : str Path to database file. tag : str A tag. index_first : str . Returns ------- result : tuple Entries. """ function_name = sys._getframe().f_code.co_name # logger.debug('{}: db_file: {} tag: {}' # .format(function_name, db_file, tag)) sql = ( """ SELECT DISTINCT entries.* FROM main_entries AS entries INNER JOIN combination_entries_tags_jids AS co ON entries.id = co.entry_id INNER JOIN main_tags AS tags ON tags.id = co.tag_id WHERE tags.tag = :tag ORDER BY entries.instances DESC LIMIT 10 OFFSET :index_first; """ ) par = { "tag": tag, "index_first": index_first } with SQLite.create_connection(db_file) as conn: cur = conn.cursor() result = cur.execute(sql, par).fetchall() return result def get_entries_recent_by_tag(db_file, tag, index_first): """ Get recent entries by a given tag. Parameters ---------- db_file : str Path to database file. tag : str A tag. index_first : str . Returns ------- result : tuple Entries. """ function_name = sys._getframe().f_code.co_name # logger.debug('{}: db_file: {} tag: {}' # .format(function_name, db_file, tag)) sql = ( """ SELECT DISTINCT entries.* FROM main_entries AS entries INNER JOIN combination_entries_tags_jids AS co ON entries.id = co.entry_id INNER JOIN main_tags AS tags ON tags.id = co.tag_id WHERE tags.tag = :tag ORDER BY date_last DESC LIMIT 10 OFFSET :index_first; """ ) par = { "tag": tag, "index_first": index_first } with SQLite.create_connection(db_file) as conn: cur = conn.cursor() result = cur.execute(sql, par).fetchall() return result def get_entries_new_by_tag(db_file, tag, index_first): """ Get new entries by a given tag. Parameters ---------- db_file : str Path to database file. tag : str A tag. index_first : str . Returns ------- result : tuple Entries. """ function_name = sys._getframe().f_code.co_name # logger.debug('{}: db_file: {} tag: {}' # .format(function_name, db_file, tag)) sql = ( """ SELECT DISTINCT entries.* FROM main_entries AS entries INNER JOIN combination_entries_tags_jids AS co ON entries.id = co.entry_id INNER JOIN main_tags AS tags ON tags.id = co.tag_id WHERE tags.tag = :tag ORDER BY date_first DESC LIMIT 10 OFFSET :index_first; """ ) par = { "tag": tag, "index_first": index_first } with SQLite.create_connection(db_file) as conn: cur = conn.cursor() result = cur.execute(sql, par).fetchall() return result def get_tags_30(db_file): """ Get 30 tags. Parameters ---------- db_file : str Path to database file. Returns ------- result : tuple Tags and number of instances. """ function_name = sys._getframe().f_code.co_name # logger.debug('{}: db_file: {} index_first: {}' # .format(function_name, db_file, index_first)) sql = ( """ SELECT tag, instances FROM main_tags ORDER BY instances DESC LIMIT 30; """ ) with SQLite.create_connection(db_file) as conn: cur = conn.cursor() result = cur.execute(sql).fetchall() return result def get_30_tags_by_entries_popular(db_file, index_first): """ Get 30 tags by currently viewed popular entries. Parameters ---------- db_file : str Path to database file. index_first : str . Returns ------- result : tuple Tags and number of instances. """ function_name = sys._getframe().f_code.co_name # logger.debug('{}: db_file: {} index_first: {}' # .format(function_name, db_file, index_first)) sql = ( """ SELECT DISTINCT mt.tag, mt.instances FROM combination_entries_tags_jids AS co INNER JOIN main_tags AS mt ON mt.id = co.tag_id WHERE co.entry_id IN ( SELECT id FROM main_entries ORDER BY instances DESC LIMIT 10 OFFSET ? ) ORDER BY mt.instances DESC LIMIT 30; """ ) par = (index_first,) with SQLite.create_connection(db_file) as conn: cur = conn.cursor() result = cur.execute(sql, par).fetchall() return result def get_30_tags_by_entries_new_by_tag(db_file, tag, index_first): """ Get 30 tags by currently viewed new entries by a given tag. Parameters ---------- db_file : str Path to database file. index_first : str . Returns ------- result : tuple Tags and number of instances. """ function_name = sys._getframe().f_code.co_name # logger.debug('{}: db_file: {} index_first: {}' # .format(function_name, db_file, index_first)) sql = ( """ SELECT DISTINCT mt.tag, mt.instances FROM combination_entries_tags_jids AS co INNER JOIN main_tags AS mt ON mt.id = co.tag_id WHERE co.entry_id IN ( SELECT DISTINCT entries.id FROM main_entries AS entries INNER JOIN combination_entries_tags_jids AS co ON entries.id = co.entry_id INNER JOIN main_tags AS tags ON tags.id = co.tag_id WHERE tags.tag = :tag ORDER BY date_first DESC LIMIT 10 OFFSET :index_first ) ORDER BY mt.instances DESC LIMIT 30; """ ) par = { "tag": tag, "index_first": index_first } with SQLite.create_connection(db_file) as conn: cur = conn.cursor() result = cur.execute(sql, par).fetchall() return result def get_30_tags_by_entries_popular_by_tag(db_file, tag, index_first): """ Get 30 tags by currently viewed popular entries by a given tag. Parameters ---------- db_file : str Path to database file. index_first : str . Returns ------- result : tuple Tags and number of instances. """ function_name = sys._getframe().f_code.co_name # logger.debug('{}: db_file: {} index_first: {}' # .format(function_name, db_file, index_first)) sql = ( """ SELECT DISTINCT mt.tag, mt.instances FROM combination_entries_tags_jids AS co INNER JOIN main_tags AS mt ON mt.id = co.tag_id WHERE co.entry_id IN ( SELECT DISTINCT entries.id FROM main_entries AS entries INNER JOIN combination_entries_tags_jids AS co ON entries.id = co.entry_id INNER JOIN main_tags AS tags ON tags.id = co.tag_id WHERE tags.tag = :tag ORDER BY entries.instances DESC LIMIT 10 OFFSET :index_first ) ORDER BY mt.instances DESC LIMIT 30; """ ) par = { "tag": tag, "index_first": index_first } with SQLite.create_connection(db_file) as conn: cur = conn.cursor() result = cur.execute(sql, par).fetchall() return result def get_30_tags_by_entries_recent_by_tag(db_file, tag, index_first): """ Get 30 tags by currently viewed recent entries by a given tag. Parameters ---------- db_file : str Path to database file. index_first : str . Returns ------- result : tuple Tags and number of instances. """ function_name = sys._getframe().f_code.co_name # logger.debug('{}: db_file: {} index_first: {}' # .format(function_name, db_file, index_first)) sql = ( """ SELECT DISTINCT mt.tag, mt.instances FROM combination_entries_tags_jids AS co INNER JOIN main_tags AS mt ON mt.id = co.tag_id WHERE co.entry_id IN ( SELECT DISTINCT entries.id FROM main_entries AS entries INNER JOIN combination_entries_tags_jids AS co ON entries.id = co.entry_id INNER JOIN main_tags AS tags ON tags.id = co.tag_id WHERE tags.tag = :tag ORDER BY date_last DESC LIMIT 10 OFFSET :index_first ) ORDER BY mt.instances DESC LIMIT 30; """ ) par = { "tag": tag, "index_first": index_first } with SQLite.create_connection(db_file) as conn: cur = conn.cursor() result = cur.execute(sql, par).fetchall() return result def get_30_tags_by_entries_new(db_file, index_first): """ Get 30 tags by currently viewed new entries. Parameters ---------- db_file : str Path to database file. index_first : str . Returns ------- result : tuple Tags and number of instances. """ function_name = sys._getframe().f_code.co_name # logger.debug('{}: db_file: {} index_first: {}' # .format(function_name, db_file, index_first)) sql = ( """ SELECT DISTINCT mt.tag, mt.instances FROM combination_entries_tags_jids AS co INNER JOIN main_tags AS mt ON mt.id = co.tag_id WHERE co.entry_id IN ( SELECT id FROM main_entries ORDER BY date_first DESC LIMIT 10 OFFSET ? ) ORDER BY mt.instances DESC LIMIT 30; """ ) par = (index_first,) with SQLite.create_connection(db_file) as conn: cur = conn.cursor() result = cur.execute(sql, par).fetchall() return result def get_30_tags_by_entries_recent(db_file, index_first): """ Get 30 tags by currently viewed recent entries. Parameters ---------- db_file : str Path to database file. index_first : str . Returns ------- result : tuple Tags and number of instances. """ function_name = sys._getframe().f_code.co_name # logger.debug('{}: db_file: {} index_first: {}' # .format(function_name, db_file, index_first)) sql = ( """ SELECT DISTINCT mt.tag, mt.instances FROM combination_entries_tags_jids AS co INNER JOIN main_tags AS mt ON mt.id = co.tag_id WHERE co.entry_id IN ( SELECT id FROM main_entries ORDER BY date_last DESC LIMIT 10 OFFSET ? ) ORDER BY mt.instances DESC LIMIT 30; """ ) par = (index_first,) with SQLite.create_connection(db_file) as conn: cur = conn.cursor() result = cur.execute(sql, par).fetchall() return result def get_30_tags_by_entries_by_query_recent(db_file, query, index_first): """ Get 30 tags by currently viewed entries by query. Parameters ---------- db_file : str Path to database file. query : str A search query. index_first : str . Returns ------- result : tuple Tags and number of instances. """ function_name = sys._getframe().f_code.co_name # logger.debug('{}: db_file: {} index_first: {}' # .format(function_name, db_file, index_first)) sql = ( """ SELECT DISTINCT mt.tag, mt.instances FROM combination_entries_tags_jids AS co INNER JOIN main_tags AS mt ON mt.id = co.tag_id WHERE co.entry_id IN ( SELECT id FROM main_entries WHERE title LIKE :query OR url LIKE :query OR summary LIKE :query ORDER BY instances DESC LIMIT 10 OFFSET :index_first ) ORDER BY mt.instances DESC LIMIT 30; """ ) par = { "query": f'%{query}%', "index_first": index_first } with SQLite.create_connection(db_file) as conn: cur = conn.cursor() result = cur.execute(sql, par).fetchall() return result def get_30_tags_by_jid_and_tag(db_file, jid, tag, index_first): """ Get 30 tags by Jabber ID and tags. Parameters ---------- db_file : str Path to database file. jid : str Jabber ID. tag : str A tag. index_first : str . Returns ------- result : tuple Tags and number of instances. """ function_name = sys._getframe().f_code.co_name # logger.debug('{}: db_file: {} index_first: {}' # .format(function_name, db_file, index_first)) sql = ( """ SELECT DISTINCT mt.tag, mt.instances FROM combination_entries_tags_jids AS co INNER JOIN main_tags AS mt ON mt.id = co.tag_id WHERE co.entry_id IN ( SELECT co.entry_id FROM main_entries AS me INNER JOIN combination_entries_tags_jids AS co ON co.entry_id = me.id INNER JOIN main_jids AS mj ON mj.id = co.jid_id INNER JOIN main_tags AS mt ON mt.id = co.tag_id WHERE mj.jid = :jid AND mt.tag = :tag LIMIT 10 OFFSET :index_first ) ORDER BY mt.instances DESC LIMIT 30; """ ) par = { "jid": jid, "tag": tag, "index_first": index_first } with SQLite.create_connection(db_file) as conn: cur = conn.cursor() result = cur.execute(sql, par).fetchall() return result def get_30_tags_by_jid_and_query(db_file, jid, query, index_first): """ Get 30 tags by Jabber ID and query. Parameters ---------- db_file : str Path to database file. jid : str Jabber ID. query : str A search query. index_first : str . Returns ------- result : tuple Tags and number of instances. """ function_name = sys._getframe().f_code.co_name # logger.debug('{}: db_file: {} index_first: {}' # .format(function_name, db_file, index_first)) sql = ( """ SELECT DISTINCT mt.tag, mt.instances FROM combination_entries_tags_jids AS co INNER JOIN main_tags AS mt ON mt.id = co.tag_id WHERE co.entry_id IN ( SELECT co.entry_id FROM main_entries AS me INNER JOIN combination_entries_tags_jids AS co ON co.entry_id = me.id INNER JOIN main_jids AS mj ON mj.id = co.jid_id INNER JOIN main_tags AS mt ON mt.id = co.tag_id WHERE mj.jid = :jid AND (title LIKE :query OR url LIKE :query OR summary LIKE :query) LIMIT 10 OFFSET :index_first ) ORDER BY mt.instances DESC LIMIT 30; """ ) par = { "jid": jid, "query": f'%{query}%', "index_first": index_first } with SQLite.create_connection(db_file) as conn: cur = conn.cursor() result = cur.execute(sql, par).fetchall() return result def get_30_tags_by_jid(db_file, jid, index_first): """ Get 30 tags by Jabber ID. Parameters ---------- db_file : str Path to database file. jid : str Jabber ID. Returns ------- result : tuple Tags and number of instances. """ function_name = sys._getframe().f_code.co_name # logger.debug('{}: db_file: {} index_first: {}' # .format(function_name, db_file, index_first)) sql = ( """ SELECT DISTINCT mt.tag, mt.instances FROM combination_entries_tags_jids AS co INNER JOIN main_tags AS mt ON mt.id = co.tag_id WHERE co.entry_id IN ( SELECT DISTINCT me.id FROM main_entries AS me INNER JOIN combination_entries_tags_jids AS co ON co.entry_id = me.id INNER JOIN main_jids AS mj ON mj.id = co.jid_id WHERE mj.jid = :jid ORDER BY instances DESC LIMIT 10 OFFSET :index_first ) ORDER BY mt.instances DESC LIMIT 30; """ ) par = { "jid": jid, "index_first": index_first } with SQLite.create_connection(db_file) as conn: cur = conn.cursor() result = cur.execute(sql, par).fetchall() return result def get_tags_500(db_file): """ Get 500 tags. Parameters ---------- db_file : str Path to database file. Returns ------- result : tuple Tags and number of instances. """ function_name = sys._getframe().f_code.co_name # logger.debug('{}: db_file: {}' # .format(function_name, db_file)) sql = ( """ WITH Common500Tags AS ( SELECT tag, instances FROM main_tags ORDER BY instances DESC LIMIT 500 ) SELECT tag, instances FROM Common500Tags ORDER BY tag ASC; """ ) with SQLite.create_connection(db_file) as conn: cur = conn.cursor() result = cur.execute(sql).fetchall() return result def get_500_tags_by_jid_sorted_by_name(db_file, jid): """ Get 500 tags by Jabber ID, sorted by name. Parameters ---------- db_file : str Path to database file. jid : str Jabber ID. Returns ------- result : tuple Tags and number of instances. """ function_name = sys._getframe().f_code.co_name # logger.debug('{}: db_file: {} index_first: {}' # .format(function_name, db_file, index_first)) sql = ( """ SELECT mt.tag, COUNT(*) AS instances FROM main_tags mt JOIN combination_entries_tags_jids combination ON mt.id = combination.tag_id JOIN main_jids mj ON combination.jid_id = mj.id WHERE mj.jid = :jid GROUP BY mt.tag LIMIT 500; """ ) par = { "jid": jid } with SQLite.create_connection(db_file) as conn: cur = conn.cursor() result = cur.execute(sql, par).fetchall() return result def get_500_tags_by_jid_sorted_by_instance(db_file, jid): """ Get 500 tags by Jabber ID, sorted by instance. Parameters ---------- db_file : str Path to database file. jid : str Jabber ID. Returns ------- result : tuple Tags and number of instances. """ function_name = sys._getframe().f_code.co_name # logger.debug('{}: db_file: {} index_first: {}' # .format(function_name, db_file, index_first)) sql = ( """ SELECT mt.tag, COUNT(*) AS instances FROM main_tags mt JOIN combination_entries_tags_jids combination ON mt.id = combination.tag_id JOIN main_jids mj ON combination.jid_id = mj.id WHERE mj.jid = :jid GROUP BY mt.tag ORDER BY instances DESC LIMIT 500; """ ) par = { "jid": jid } with SQLite.create_connection(db_file) as conn: cur = conn.cursor() result = cur.execute(sql, par).fetchall() return result # FIXME It appear that the wrong table is fetched # The table to be fetched is combination_entries_tags_jids def is_jid_associated_with_url_hash(db_file, jid, url_hash): """ Check whether a given Jabber ID is associated with a given URL hash. Parameters ---------- db_file : str Path to database file. jid : str A Jabber ID. url_hash : str An MD5 checksuum of a URL. Returns ------- result : tuple Tags. """ function_name = sys._getframe().f_code.co_name # logger.debug('{}: db_file: {} jid: {} url_hash: {}' # .format(function_name, db_file, jid, url_hash)) sql = ( """ SELECT mj.jid, me.url_hash FROM main_jids AS mj INNER JOIN combination_entries_tags_jids AS co ON mj.id = co.jid_id INNER JOIN main_entries AS me ON me.id = co.entry_id WHERE mj.jid = :jid AND me.url_hash = :url_hash; """ ) par = { "jid": jid, "url_hash": url_hash } with SQLite.create_connection(db_file) as conn: cur = conn.cursor() result = cur.execute(sql, par).fetchone() return result[0] if result and len(result) == 1 else result #deassociate_entry_from_jid async def delete_combination_row_by_jid_and_url_hash(db_file, url_hash, jid): """ Remove association of a given Jabber ID and a given URL hash. Parameters ---------- db_file : str Path to database file. jid : str A Jabber ID. url_hash : str An MD5 checksuum of a URL. Returns ------- None. """ function_name = sys._getframe().f_code.co_name # logger.debug('{}: db_file: {} jid: {} url_hash: {}' # .format(function_name, db_file, jid, url_hash)) sql = ( """ DELETE FROM combination_entries_tags_jids WHERE id IN ( SELECT co.id FROM combination_entries_tags_jids co JOIN main_entries me ON co.entry_id = me.id JOIN main_jids mj ON co.jid_id = mj.id WHERE me.url_hash = :url_hash AND mj.jid = :jid ); """ ) par = { "jid": jid, "url_hash": url_hash } async with DBLOCK: with SQLite.create_connection(db_file) as conn: cur = conn.cursor() cur.execute(sql, par) # NOTE The result was ordered by number of instances # ORDER BY main_tags.instances DESC # And has been changed to order of alphabet # ORDER BY main_tags.tag ASC def get_tags_by_entry_id(db_file, entry_id): """ Get tags by an ID entry. Parameters ---------- db_file : str Path to database file. entry_id : str An ID of an entry. Returns ------- result : tuple Tags. """ function_name = sys._getframe().f_code.co_name # logger.debug('{}: db_file: {} index_first: {}' # .format(function_name, db_file, index_first)) sql = ( """ SELECT DISTINCT main_tags.tag FROM main_tags INNER JOIN combination_entries_tags_jids ON main_tags.id = combination_entries_tags_jids.tag_id WHERE combination_entries_tags_jids.entry_id = ? ORDER BY main_tags.tag ASC LIMIT 5; """ ) par = (entry_id,) with SQLite.create_connection(db_file) as conn: cur = conn.cursor() result = cur.execute(sql, par).fetchall() return result def get_jid_id_by_jid(db_file, jid): """ Get id of a given jid. Parameters ---------- db_file : str Path to database file. jid : str Jabber ID. Returns ------- result : tuple ID. """ function_name = sys._getframe().f_code.co_name # logger.debug('{}: db_file: {} jid: {}' # .format(function_name, db_file, jid)) sql = ( """ SELECT id FROM main_jids WHERE jid = ?; """ ) par = (jid,) with SQLite.create_connection(db_file) as conn: cur = conn.cursor() result = cur.execute(sql, par).fetchone() return result[0] if result and len(result) == 1 else result def get_jid_by_jid_id(db_file, jid_id): """ Get jid of a given jid_id. Parameters ---------- db_file : str Path to database file. jid_id : str ID of Jabber ID. Returns ------- result : tuple ID. """ function_name = sys._getframe().f_code.co_name # logger.debug('{}: db_file: {} jid_id: {}' # .format(function_name, db_file, jid_id)) sql = ( """ SELECT jid FROM main_jids WHERE id = ?; """ ) par = (jid_id,) with SQLite.create_connection(db_file) as conn: cur = conn.cursor() result = cur.execute(sql, par).fetchone() return result[0] if result and len(result) == 1 else result