artemis/core/data/schema/versions/SDGT_2_upgrade.sql

71 lines
2.3 KiB
SQL

SET FOREIGN_KEY_CHECKS=0;
-- WARNING: This script is NOT idempotent! MAKE A BACKUP BEFORE RUNNING THIS SCRIPT!
-- Create the new table idac_user_vs_course_info
CREATE TABLE idac_user_vs_course_info (
id INT PRIMARY KEY AUTO_INCREMENT,
user INT,
battle_mode INT,
course_id INT,
vs_cnt INT,
vs_win INT,
CONSTRAINT idac_user_vs_course_info_fk FOREIGN KEY (user) REFERENCES aime_user(id) ON DELETE CASCADE ON UPDATE CASCADE,
UNIQUE KEY idac_user_vs_course_info_uk (user, battle_mode, course_id)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;
-- Insert data from the original table to the new tables
INSERT INTO idac_user_vs_course_info (user, battle_mode, course_id, vs_cnt, vs_win)
SELECT user, 1 as battle_mode, course_id, COUNT(winning) as vs_cnt, SUM(win_flg) as vs_win
FROM idac_user_vs_info
GROUP BY user, course_id;
-- Drop UK idac_user_vs_info_uk
ALTER TABLE idac_user_vs_info
DROP FOREIGN KEY idac_user_vs_info_ibfk_1,
DROP INDEX idac_user_vs_info_uk;
-- Drop/Add the old columns from the original table
ALTER TABLE idac_user_vs_info
DROP COLUMN group_key,
DROP COLUMN win_flg,
DROP COLUMN style_car_id,
DROP COLUMN course_id,
DROP COLUMN course_day,
DROP COLUMN players_num,
DROP COLUMN winning,
DROP COLUMN advantage_1,
DROP COLUMN advantage_2,
DROP COLUMN advantage_3,
DROP COLUMN advantage_4,
DROP COLUMN select_course_id,
DROP COLUMN select_course_day,
DROP COLUMN select_course_random,
DROP COLUMN matching_success_sec,
DROP COLUMN boost_flag,
ADD COLUMN battle_mode TINYINT UNSIGNED DEFAULT 1 NOT NULL AFTER user,
ADD COLUMN invalid INT DEFAULT 0,
ADD COLUMN str INT DEFAULT 0,
ADD COLUMN str_now INT DEFAULT 0,
ADD COLUMN lose_now INT DEFAULT 0;
-- Create a temporary table to store the records you want to keep
CREATE TEMPORARY TABLE temp_table AS
SELECT MIN(id) AS min_id
FROM idac_user_vs_info
GROUP BY battle_mode, user;
-- Delete records from the original table based on the temporary table
DELETE FROM idac_user_vs_info
WHERE id NOT IN (SELECT min_id FROM temp_table);
-- Drop the temporary table
DROP TEMPORARY TABLE IF EXISTS temp_table;
-- Add UK idac_user_vs_info_uk
ALTER TABLE idac_user_vs_info
ADD CONSTRAINT idac_user_vs_info_ibfk_1 FOREIGN KEY (user) REFERENCES aime_user(id) ON DELETE CASCADE ON UPDATE CASCADE,
ADD UNIQUE KEY idac_user_vs_info_uk (user, battle_mode);
SET FOREIGN_KEY_CHECKS=1;