Files
AnonBot/database/schema.sql

148 lines
5.5 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')),
user_question_number INTEGER,
-- Внешние ключи
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_questions_user_question_number ON questions(to_user_id, user_question_number);
CREATE UNIQUE INDEX idx_questions_user_number_unique ON questions(to_user_id, user_question_number) WHERE status != 'deleted';
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;
-- Триггер для автоматического вычисления user_question_number при вставке
CREATE TRIGGER calculate_user_question_number
AFTER INSERT ON questions
FOR EACH ROW
WHEN NEW.user_question_number IS NULL
BEGIN
UPDATE questions
SET user_question_number = (
SELECT COALESCE(MAX(user_question_number), 0) + 1
FROM questions q2
WHERE q2.to_user_id = NEW.to_user_id
AND q2.status != 'deleted'
)
WHERE id = NEW.id;
END;
-- Триггер для пересчета номеров при удалении вопроса
CREATE TRIGGER recalculate_user_question_numbers_on_delete
AFTER UPDATE ON questions
FOR EACH ROW
WHEN NEW.status = 'deleted' AND OLD.status != 'deleted'
BEGIN
-- Устанавливаем user_question_number в NULL для удаленного вопроса
UPDATE questions
SET user_question_number = NULL
WHERE id = NEW.id;
-- Пересчитываем номера для всех вопросов пользователя после удаленного
UPDATE questions
SET user_question_number = user_question_number - 1
WHERE to_user_id = NEW.to_user_id
AND user_question_number > OLD.user_question_number
AND status != 'deleted'
AND id != NEW.id;
END;