feat: Переделка Telegram интеграции на единого бота (v2.1.0)
All checks were successful
Build and Push Docker Image / build-and-push (push) Successful in 54s
All checks were successful
Build and Push Docker Image / build-and-push (push) Successful in 54s
- Единый бот для всех пользователей (токен из .env) - Deep link для подключения через /start команду - Отдельная таблица todoist_integrations для Todoist webhook - Персональные отчеты для каждого пользователя - Автоматическое применение миграции 012 при старте - Обновлен Frontend: кнопка подключения вместо поля ввода токена
This commit is contained in:
@@ -0,0 +1,103 @@
|
||||
-- Migration: Refactor telegram_integrations for single shared bot
|
||||
-- and move Todoist webhook_token to separate table
|
||||
|
||||
-- ============================================
|
||||
-- 1. Создаем таблицу todoist_integrations
|
||||
-- ============================================
|
||||
CREATE TABLE IF NOT EXISTS todoist_integrations (
|
||||
id SERIAL PRIMARY KEY,
|
||||
user_id INTEGER NOT NULL REFERENCES users(id) ON DELETE CASCADE,
|
||||
webhook_token VARCHAR(255) NOT NULL,
|
||||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||
CONSTRAINT todoist_integrations_user_id_unique UNIQUE (user_id)
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX IF NOT EXISTS idx_todoist_integrations_webhook_token
|
||||
ON todoist_integrations(webhook_token);
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_todoist_integrations_user_id
|
||||
ON todoist_integrations(user_id);
|
||||
|
||||
COMMENT ON TABLE todoist_integrations IS 'Todoist webhook integration settings per user';
|
||||
COMMENT ON COLUMN todoist_integrations.webhook_token IS 'Unique token for Todoist webhook URL';
|
||||
|
||||
-- ============================================
|
||||
-- 2. Мигрируем webhook_token из telegram_integrations в todoist_integrations
|
||||
-- ============================================
|
||||
INSERT INTO todoist_integrations (user_id, webhook_token, created_at, updated_at)
|
||||
SELECT user_id, webhook_token, COALESCE(created_at, CURRENT_TIMESTAMP), CURRENT_TIMESTAMP
|
||||
FROM telegram_integrations
|
||||
WHERE webhook_token IS NOT NULL
|
||||
AND webhook_token != ''
|
||||
AND user_id IS NOT NULL
|
||||
ON CONFLICT (user_id) DO NOTHING;
|
||||
|
||||
-- ============================================
|
||||
-- 3. Модифицируем telegram_integrations
|
||||
-- ============================================
|
||||
|
||||
-- Удаляем bot_token (будет в .env)
|
||||
ALTER TABLE telegram_integrations
|
||||
DROP COLUMN IF EXISTS bot_token;
|
||||
|
||||
-- Удаляем webhook_token (перенесли в todoist_integrations)
|
||||
ALTER TABLE telegram_integrations
|
||||
DROP COLUMN IF EXISTS webhook_token;
|
||||
|
||||
-- Добавляем telegram_user_id
|
||||
ALTER TABLE telegram_integrations
|
||||
ADD COLUMN IF NOT EXISTS telegram_user_id BIGINT;
|
||||
|
||||
-- Добавляем start_token для deep links
|
||||
ALTER TABLE telegram_integrations
|
||||
ADD COLUMN IF NOT EXISTS start_token VARCHAR(255);
|
||||
|
||||
-- Добавляем timestamps если их нет
|
||||
ALTER TABLE telegram_integrations
|
||||
ADD COLUMN IF NOT EXISTS created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP;
|
||||
|
||||
ALTER TABLE telegram_integrations
|
||||
ADD COLUMN IF NOT EXISTS updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP;
|
||||
|
||||
-- ============================================
|
||||
-- 4. Создаем индексы
|
||||
-- ============================================
|
||||
CREATE UNIQUE INDEX IF NOT EXISTS idx_telegram_integrations_start_token
|
||||
ON telegram_integrations(start_token)
|
||||
WHERE start_token IS NOT NULL;
|
||||
|
||||
CREATE UNIQUE INDEX IF NOT EXISTS idx_telegram_integrations_telegram_user_id
|
||||
ON telegram_integrations(telegram_user_id)
|
||||
WHERE telegram_user_id IS NOT NULL;
|
||||
|
||||
-- Уникальность user_id
|
||||
DROP INDEX IF EXISTS idx_telegram_integrations_user_id;
|
||||
CREATE UNIQUE INDEX IF NOT EXISTS idx_telegram_integrations_user_id_unique
|
||||
ON telegram_integrations(user_id)
|
||||
WHERE user_id IS NOT NULL;
|
||||
|
||||
-- Индекс для поиска по chat_id
|
||||
CREATE INDEX IF NOT EXISTS idx_telegram_integrations_chat_id
|
||||
ON telegram_integrations(chat_id)
|
||||
WHERE chat_id IS NOT NULL;
|
||||
|
||||
-- Удаляем старый индекс webhook_token
|
||||
DROP INDEX IF EXISTS idx_telegram_integrations_webhook_token;
|
||||
|
||||
-- ============================================
|
||||
-- 5. Очищаем данные Telegram для переподключения
|
||||
-- ============================================
|
||||
UPDATE telegram_integrations
|
||||
SET chat_id = NULL,
|
||||
telegram_user_id = NULL,
|
||||
start_token = NULL,
|
||||
updated_at = CURRENT_TIMESTAMP;
|
||||
|
||||
-- ============================================
|
||||
-- Комментарии
|
||||
-- ============================================
|
||||
COMMENT ON COLUMN telegram_integrations.telegram_user_id IS 'Telegram user ID (message.from.id)';
|
||||
COMMENT ON COLUMN telegram_integrations.chat_id IS 'Telegram chat ID для отправки сообщений';
|
||||
COMMENT ON COLUMN telegram_integrations.start_token IS 'Временный токен для deep link при первом подключении';
|
||||
|
||||
Reference in New Issue
Block a user