92 lines
3.6 KiB
SQL
92 lines
3.6 KiB
SQL
-- 多账号迁移脚本(在已有库上执行一次)
|
||
-- 目标:
|
||
-- 1) 新增 accounts 表(存加密后的 API KEY/SECRET)
|
||
-- 2) trading_config/trades/account_snapshots 增加 account_id(默认=1)
|
||
-- 3) trading_config 的唯一约束从 config_key 改为 (account_id, config_key)
|
||
--
|
||
-- ⚠️ 注意:
|
||
-- - 不同 MySQL 版本对 "ADD COLUMN IF NOT EXISTS" 支持不一致,因此这里用 INFORMATION_SCHEMA + 动态SQL。
|
||
-- - 执行前建议先备份数据库。
|
||
|
||
USE `auto_trade_sys`;
|
||
|
||
-- 1) accounts 表
|
||
CREATE TABLE IF NOT EXISTS `accounts` (
|
||
`id` INT PRIMARY KEY AUTO_INCREMENT,
|
||
`name` VARCHAR(100) NOT NULL,
|
||
`status` VARCHAR(20) DEFAULT 'active' COMMENT 'active, disabled',
|
||
`api_key_enc` TEXT NULL COMMENT '加密后的 API KEY(enc:v1:...)',
|
||
`api_secret_enc` TEXT NULL COMMENT '加密后的 API SECRET(enc:v1:...)',
|
||
`use_testnet` BOOLEAN DEFAULT FALSE,
|
||
`created_at` TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||
`updated_at` TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='账号表(多账号)';
|
||
|
||
INSERT INTO `accounts` (`id`, `name`, `status`, `use_testnet`)
|
||
VALUES (1, 'default', 'active', false)
|
||
ON DUPLICATE KEY UPDATE `name`=VALUES(`name`);
|
||
|
||
-- 2) trading_config.account_id
|
||
SET @has_col := (
|
||
SELECT COUNT(1)
|
||
FROM INFORMATION_SCHEMA.COLUMNS
|
||
WHERE TABLE_SCHEMA = DATABASE()
|
||
AND TABLE_NAME = 'trading_config'
|
||
AND COLUMN_NAME = 'account_id'
|
||
);
|
||
SET @sql := IF(@has_col = 0, 'ALTER TABLE trading_config ADD COLUMN account_id INT NOT NULL DEFAULT 1 AFTER id', 'SELECT 1');
|
||
PREPARE stmt FROM @sql; EXECUTE stmt; DEALLOCATE PREPARE stmt;
|
||
|
||
-- 3) trades.account_id
|
||
SET @has_col := (
|
||
SELECT COUNT(1)
|
||
FROM INFORMATION_SCHEMA.COLUMNS
|
||
WHERE TABLE_SCHEMA = DATABASE()
|
||
AND TABLE_NAME = 'trades'
|
||
AND COLUMN_NAME = 'account_id'
|
||
);
|
||
SET @sql := IF(@has_col = 0, 'ALTER TABLE trades ADD COLUMN account_id INT NOT NULL DEFAULT 1 AFTER id', 'SELECT 1');
|
||
PREPARE stmt FROM @sql; EXECUTE stmt; DEALLOCATE PREPARE stmt;
|
||
|
||
-- 4) account_snapshots.account_id
|
||
SET @has_col := (
|
||
SELECT COUNT(1)
|
||
FROM INFORMATION_SCHEMA.COLUMNS
|
||
WHERE TABLE_SCHEMA = DATABASE()
|
||
AND TABLE_NAME = 'account_snapshots'
|
||
AND COLUMN_NAME = 'account_id'
|
||
);
|
||
SET @sql := IF(@has_col = 0, 'ALTER TABLE account_snapshots ADD COLUMN account_id INT NOT NULL DEFAULT 1 AFTER id', 'SELECT 1');
|
||
PREPARE stmt FROM @sql; EXECUTE stmt; DEALLOCATE PREPARE stmt;
|
||
|
||
-- 5) trading_config 唯一键:改为 (account_id, config_key)
|
||
-- 尝试删除旧 UNIQUE(config_key)(名字可能是 config_key 或其他)
|
||
SET @idx_name := (
|
||
SELECT INDEX_NAME
|
||
FROM INFORMATION_SCHEMA.STATISTICS
|
||
WHERE TABLE_SCHEMA = DATABASE()
|
||
AND TABLE_NAME = 'trading_config'
|
||
AND NON_UNIQUE = 0
|
||
AND COLUMN_NAME = 'config_key'
|
||
LIMIT 1
|
||
);
|
||
SET @sql := IF(@idx_name IS NOT NULL, CONCAT('ALTER TABLE trading_config DROP INDEX ', @idx_name), 'SELECT 1');
|
||
PREPARE stmt FROM @sql; EXECUTE stmt; DEALLOCATE PREPARE stmt;
|
||
|
||
-- 添加新唯一键(如果不存在)
|
||
SET @has_uk := (
|
||
SELECT COUNT(1)
|
||
FROM INFORMATION_SCHEMA.STATISTICS
|
||
WHERE TABLE_SCHEMA = DATABASE()
|
||
AND TABLE_NAME = 'trading_config'
|
||
AND INDEX_NAME = 'uk_account_config_key'
|
||
);
|
||
SET @sql := IF(@has_uk = 0, 'ALTER TABLE trading_config ADD UNIQUE KEY uk_account_config_key (account_id, config_key)', 'SELECT 1');
|
||
PREPARE stmt FROM @sql; EXECUTE stmt; DEALLOCATE PREPARE stmt;
|
||
|
||
-- 6) 索引(可选,老版本 MySQL 不支持 IF NOT EXISTS,可忽略报错后手动检查)
|
||
-- 如果你看到 “Duplicate key name” 可直接忽略。
|
||
CREATE INDEX idx_trades_account_id ON trades(account_id);
|
||
CREATE INDEX idx_account_snapshots_account_id ON account_snapshots(account_id);
|
||
|