all function is working added test (empty files for plan) database schema business logic rate limitting logging decorators
109 lines
4.0 KiB
SQL
109 lines
4.0 KiB
SQL
-- Схема базы данных для AnonBot
|
|
-- SQLite3 совместимая схема
|
|
|
|
-- Таблица пользователей
|
|
CREATE TABLE users (
|
|
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
|
telegram_id INTEGER UNIQUE NOT NULL,
|
|
username TEXT,
|
|
first_name TEXT NOT NULL,
|
|
last_name TEXT,
|
|
chat_id INTEGER NOT NULL,
|
|
profile_link TEXT UNIQUE NOT NULL,
|
|
is_active BOOLEAN DEFAULT TRUE,
|
|
is_superuser BOOLEAN DEFAULT FALSE,
|
|
created_at DATETIME DEFAULT CURRENT_TIMESTAMP,
|
|
updated_at DATETIME DEFAULT CURRENT_TIMESTAMP,
|
|
banned_until DATETIME,
|
|
ban_reason TEXT
|
|
);
|
|
|
|
-- Таблица вопросов
|
|
CREATE TABLE questions (
|
|
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
|
from_user_id INTEGER,
|
|
to_user_id INTEGER NOT NULL,
|
|
message_text TEXT NOT NULL,
|
|
answer_text TEXT,
|
|
is_anonymous BOOLEAN DEFAULT TRUE,
|
|
message_id INTEGER,
|
|
created_at DATETIME DEFAULT CURRENT_TIMESTAMP,
|
|
answered_at DATETIME,
|
|
is_read BOOLEAN DEFAULT FALSE,
|
|
status TEXT DEFAULT 'pending' CHECK (status IN ('pending', 'answered', 'rejected', 'deleted')),
|
|
|
|
-- Внешние ключи
|
|
FOREIGN KEY (from_user_id) REFERENCES users(telegram_id) ON DELETE CASCADE,
|
|
FOREIGN KEY (to_user_id) REFERENCES users(telegram_id) ON DELETE CASCADE
|
|
);
|
|
|
|
-- Таблица блокировок
|
|
CREATE TABLE user_blocks (
|
|
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
|
blocker_id INTEGER NOT NULL,
|
|
blocked_id INTEGER NOT NULL,
|
|
created_at DATETIME DEFAULT CURRENT_TIMESTAMP,
|
|
|
|
-- Внешние ключи и уникальность
|
|
FOREIGN KEY (blocker_id) REFERENCES users(telegram_id) ON DELETE CASCADE,
|
|
FOREIGN KEY (blocked_id) REFERENCES users(telegram_id) ON DELETE CASCADE,
|
|
UNIQUE(blocker_id, blocked_id)
|
|
);
|
|
|
|
-- Таблица настроек пользователя
|
|
CREATE TABLE user_settings (
|
|
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
|
user_id INTEGER UNIQUE NOT NULL,
|
|
allow_questions BOOLEAN DEFAULT TRUE,
|
|
notify_new_questions BOOLEAN DEFAULT TRUE,
|
|
notify_answers BOOLEAN DEFAULT TRUE,
|
|
language TEXT DEFAULT 'ru',
|
|
created_at DATETIME DEFAULT CURRENT_TIMESTAMP,
|
|
updated_at DATETIME DEFAULT CURRENT_TIMESTAMP,
|
|
|
|
-- Внешний ключ
|
|
FOREIGN KEY (user_id) REFERENCES users(telegram_id) ON DELETE CASCADE
|
|
);
|
|
|
|
-- Индексы для оптимизации запросов
|
|
CREATE INDEX idx_users_telegram_id ON users(telegram_id);
|
|
CREATE INDEX idx_users_profile_link ON users(profile_link);
|
|
CREATE INDEX idx_users_is_active ON users(is_active);
|
|
CREATE INDEX idx_users_is_superuser ON users(is_superuser);
|
|
|
|
CREATE INDEX idx_questions_to_user_id ON questions(to_user_id);
|
|
CREATE INDEX idx_questions_from_user_id ON questions(from_user_id);
|
|
CREATE INDEX idx_questions_status ON questions(status);
|
|
CREATE INDEX idx_questions_created_at ON questions(created_at);
|
|
CREATE INDEX idx_questions_is_read ON questions(is_read);
|
|
|
|
CREATE INDEX idx_user_blocks_blocker_id ON user_blocks(blocker_id);
|
|
CREATE INDEX idx_user_blocks_blocked_id ON user_blocks(blocked_id);
|
|
CREATE INDEX idx_user_blocks_created_at ON user_blocks(created_at);
|
|
|
|
CREATE INDEX idx_user_settings_user_id ON user_settings(user_id);
|
|
|
|
-- Триггер для автоматического обновления updated_at в users
|
|
CREATE TRIGGER update_users_updated_at
|
|
AFTER UPDATE ON users
|
|
FOR EACH ROW
|
|
BEGIN
|
|
UPDATE users SET updated_at = CURRENT_TIMESTAMP WHERE id = NEW.id;
|
|
END;
|
|
|
|
-- Триггер для автоматического обновления updated_at в user_settings
|
|
CREATE TRIGGER update_user_settings_updated_at
|
|
AFTER UPDATE ON user_settings
|
|
FOR EACH ROW
|
|
BEGIN
|
|
UPDATE user_settings SET updated_at = CURRENT_TIMESTAMP WHERE id = NEW.id;
|
|
END;
|
|
|
|
-- Триггер для автоматического создания настроек при добавлении пользователя
|
|
CREATE TRIGGER create_user_settings
|
|
AFTER INSERT ON users
|
|
FOR EACH ROW
|
|
BEGIN
|
|
INSERT OR IGNORE INTO user_settings (user_id) VALUES (NEW.telegram_id);
|
|
END;
|