- Added `ca-certificates` installation to Dockerfile for improved network security. - Updated health check command in Dockerfile to include better timeout handling. - Refactored `run_helper.py` to implement proper signal handling and logging during shutdown. - Transitioned database operations to an asynchronous model in `async_db.py`, improving performance and responsiveness. - Updated database schema to support new foreign key relationships and optimized indexing for better query performance. - Enhanced various bot handlers to utilize async database methods, improving overall efficiency and user experience. - Removed obsolete database and fix scripts to streamline the project structure.
114 lines
4.2 KiB
SQL
114 lines
4.2 KiB
SQL
-- Telegram Helper Bot Database Schema
|
|
-- Compatible with Docker container deployment
|
|
|
|
-- IMPORTANT: Enable foreign key support after each database connection
|
|
-- PRAGMA foreign_keys = ON;
|
|
|
|
-- Note: sqlite_sequence table is automatically created by SQLite for AUTOINCREMENT fields
|
|
-- No need to create it manually
|
|
|
|
-- Users who have listened to audio messages
|
|
CREATE TABLE IF NOT EXISTS user_audio_listens (
|
|
file_name TEXT NOT NULL,
|
|
user_id INTEGER NOT NULL,
|
|
PRIMARY KEY (file_name, user_id),
|
|
FOREIGN KEY (user_id) REFERENCES our_users(user_id) ON DELETE CASCADE
|
|
);
|
|
|
|
-- Reference table for audio messages
|
|
CREATE TABLE IF NOT EXISTS audio_message_reference (
|
|
id INTEGER NOT NULL PRIMARY KEY AUTOINCREMENT,
|
|
file_name TEXT NOT NULL UNIQUE,
|
|
author_id INTEGER NOT NULL,
|
|
date_added INTEGER NOT NULL,
|
|
FOREIGN KEY (author_id) REFERENCES our_users(user_id) ON DELETE CASCADE
|
|
);
|
|
|
|
-- Bot administrators
|
|
CREATE TABLE IF NOT EXISTS admins (
|
|
user_id INTEGER NOT NULL PRIMARY KEY,
|
|
role TEXT,
|
|
FOREIGN KEY (user_id) REFERENCES our_users(user_id) ON DELETE CASCADE
|
|
);
|
|
|
|
-- User blacklist for banned users
|
|
CREATE TABLE IF NOT EXISTS blacklist (
|
|
user_id INTEGER NOT NULL PRIMARY KEY,
|
|
message_for_user TEXT,
|
|
date_to_unban INTEGER,
|
|
created_at INTEGER DEFAULT (strftime('%s', 'now')),
|
|
FOREIGN KEY (user_id) REFERENCES our_users(user_id) ON DELETE CASCADE
|
|
);
|
|
|
|
-- User message history
|
|
CREATE TABLE IF NOT EXISTS user_messages (
|
|
id INTEGER NOT NULL PRIMARY KEY AUTOINCREMENT,
|
|
message_text TEXT,
|
|
user_id INTEGER,
|
|
telegram_message_id INTEGER NOT NULL,
|
|
date INTEGER NOT NULL,
|
|
FOREIGN KEY (user_id) REFERENCES our_users(user_id) ON DELETE CASCADE
|
|
);
|
|
|
|
-- Suggested posts from Telegram
|
|
CREATE TABLE IF NOT EXISTS post_from_telegram_suggest (
|
|
message_id INTEGER NOT NULL PRIMARY KEY,
|
|
text TEXT,
|
|
helper_text_message_id INTEGER,
|
|
author_id INTEGER,
|
|
created_at INTEGER NOT NULL,
|
|
FOREIGN KEY (author_id) REFERENCES our_users(user_id) ON DELETE CASCADE
|
|
);
|
|
|
|
-- Links between posts and content
|
|
CREATE TABLE IF NOT EXISTS message_link_to_content (
|
|
post_id INTEGER NOT NULL,
|
|
message_id INTEGER NOT NULL,
|
|
PRIMARY KEY (post_id, message_id),
|
|
FOREIGN KEY (post_id) REFERENCES post_from_telegram_suggest(message_id) ON DELETE CASCADE
|
|
);
|
|
|
|
-- Content associated with Telegram posts
|
|
CREATE TABLE IF NOT EXISTS content_post_from_telegram (
|
|
message_id INTEGER NOT NULL,
|
|
content_name TEXT NOT NULL,
|
|
content_type TEXT,
|
|
PRIMARY KEY (message_id, content_name),
|
|
FOREIGN KEY (message_id) REFERENCES post_from_telegram_suggest(message_id) ON DELETE CASCADE
|
|
);
|
|
|
|
-- Bot users information (user_id is now PRIMARY KEY)
|
|
CREATE TABLE IF NOT EXISTS our_users (
|
|
user_id INTEGER NOT NULL PRIMARY KEY,
|
|
first_name TEXT,
|
|
full_name TEXT,
|
|
username TEXT,
|
|
is_bot BOOLEAN DEFAULT 0,
|
|
language_code TEXT,
|
|
has_stickers BOOLEAN DEFAULT 0 NOT NULL,
|
|
emoji TEXT,
|
|
date_added INTEGER NOT NULL,
|
|
date_changed INTEGER NOT NULL,
|
|
voice_bot_welcome_received BOOLEAN DEFAULT 0
|
|
);
|
|
|
|
-- Audio moderation tracking
|
|
CREATE TABLE IF NOT EXISTS audio_moderate (
|
|
user_id INTEGER NOT NULL,
|
|
message_id INTEGER,
|
|
PRIMARY KEY (user_id, message_id),
|
|
FOREIGN KEY (user_id) REFERENCES our_users(user_id) ON DELETE CASCADE
|
|
);
|
|
|
|
-- Create indexes for better performance
|
|
-- Optimized index for user_audio_listens - only user_id for "show all audio listened by user X"
|
|
CREATE INDEX IF NOT EXISTS idx_user_audio_listens_user_id ON user_audio_listens(user_id);
|
|
CREATE INDEX IF NOT EXISTS idx_audio_message_reference_author_id ON audio_message_reference(author_id);
|
|
CREATE INDEX IF NOT EXISTS idx_user_messages_user_id ON user_messages(user_id);
|
|
CREATE INDEX IF NOT EXISTS idx_post_from_telegram_suggest_author_id ON post_from_telegram_suggest(author_id);
|
|
CREATE INDEX IF NOT EXISTS idx_blacklist_date_to_unban ON blacklist(date_to_unban);
|
|
CREATE INDEX IF NOT EXISTS idx_user_messages_date ON user_messages(date);
|
|
CREATE INDEX IF NOT EXISTS idx_audio_message_reference_date ON audio_message_reference(date_added);
|
|
CREATE INDEX IF NOT EXISTS idx_post_from_telegram_suggest_date ON post_from_telegram_suggest(created_at);
|
|
CREATE INDEX IF NOT EXISTS idx_our_users_date_changed ON our_users(date_changed);
|