89 lines
		
	
	
		
			3.1 KiB
		
	
	
	
		
			SQL
		
	
	
	
	
	
			
		
		
	
	
			89 lines
		
	
	
		
			3.1 KiB
		
	
	
	
		
			SQL
		
	
	
	
	
	
SET FOREIGN_KEY_CHECKS = 0;
 | 
						|
 | 
						|
-- Tables no longer needed as old dashboard is decomm.
 | 
						|
DROP TABLE IF EXISTS guild_users;
 | 
						|
DROP TABLE IF EXISTS events;
 | 
						|
 | 
						|
CREATE TABLE users_new
 | 
						|
(
 | 
						|
    id                     BIGINT UNSIGNED,
 | 
						|
    dm_channel             INT UNSIGNED UNIQUE              NOT NULL,
 | 
						|
    timezone               VARCHAR(32)                      NOT NULL DEFAULT 'UTC',
 | 
						|
    meridian_time          BOOLEAN                          NOT NULL DEFAULT 0,
 | 
						|
    allowed_dm             BOOLEAN                          NOT NULL DEFAULT 1,
 | 
						|
    reset_inputs_on_create BOOLEAN                          NOT NULL DEFAULT 0,
 | 
						|
    use_browser_timezone   BOOLEAN                          NOT NULL DEFAULT 1,
 | 
						|
    dashboard_color_scheme ENUM ('system', 'light', 'dark') NOT NULL DEFAULT 'system',
 | 
						|
 | 
						|
    PRIMARY KEY (id),
 | 
						|
    FOREIGN KEY `fk_user_dm_channel` (dm_channel) REFERENCES channels (id) ON DELETE RESTRICT,
 | 
						|
    -- Useful for bot startup times
 | 
						|
    INDEX `index_timezone` (timezone)
 | 
						|
);
 | 
						|
 | 
						|
-- Drop some dodgy user entries
 | 
						|
CREATE TEMPORARY TABLE dupe_users
 | 
						|
SELECT dm_channel
 | 
						|
FROM users u1
 | 
						|
WHERE (SELECT COUNT(1) FROM users u2 WHERE u2.dm_channel = u1.dm_channel) > 1;
 | 
						|
 | 
						|
DELETE
 | 
						|
FROM users
 | 
						|
WHERE dm_channel IN (SELECT * FROM dupe_users);
 | 
						|
 | 
						|
INSERT INTO users_new (id, dm_channel, timezone, meridian_time, allowed_dm)
 | 
						|
SELECT `user`, dm_channel, IFNULL(timezone, 'UTC'), meridian_time, allowed_dm
 | 
						|
FROM users;
 | 
						|
 | 
						|
-- Add new user ID column
 | 
						|
ALTER TABLE todos
 | 
						|
    ADD COLUMN user_id_new BIGINT UNSIGNED;
 | 
						|
-- Reference new table with new column
 | 
						|
ALTER TABLE todos
 | 
						|
    ADD CONSTRAINT `todos_user_fk` FOREIGN KEY (user_id_new) REFERENCES users_new (id) ON DELETE SET NULL ON UPDATE CASCADE;
 | 
						|
-- Populate new column
 | 
						|
UPDATE todos
 | 
						|
SET user_id_new = (SELECT user FROM users WHERE id = user_id);
 | 
						|
-- Prepare a statement to drop the old constraint
 | 
						|
SELECT @todo_query := CONCAT('ALTER TABLE todos DROP FOREIGN KEY ', constraint_name)
 | 
						|
FROM information_schema.key_column_usage
 | 
						|
WHERE constraint_schema = DATABASE()
 | 
						|
  AND table_name = 'todos'
 | 
						|
  AND column_name = 'user_id';
 | 
						|
PREPARE todo_stmt FROM @todo_query;
 | 
						|
EXECUTE todo_stmt;
 | 
						|
-- Drop old column
 | 
						|
ALTER TABLE todos
 | 
						|
    DROP COLUMN user_id;
 | 
						|
-- Rename new column
 | 
						|
ALTER TABLE todos RENAME COLUMN user_id_new TO user_id;
 | 
						|
 | 
						|
-- Add new set by column
 | 
						|
ALTER TABLE reminders
 | 
						|
    ADD COLUMN set_by_new BIGINT UNSIGNED;
 | 
						|
-- Reference new table with new column
 | 
						|
ALTER TABLE reminders
 | 
						|
    ADD CONSTRAINT `reminders_set_by_fk` FOREIGN KEY (set_by_new) REFERENCES users_new (id) ON DELETE SET NULL ON UPDATE CASCADE;
 | 
						|
-- Populate new column
 | 
						|
UPDATE reminders
 | 
						|
SET set_by_new = (SELECT user FROM users WHERE id = set_by);
 | 
						|
-- Prepare a statement to drop the old constraint
 | 
						|
SELECT @reminders_query := CONCAT('ALTER TABLE reminders DROP FOREIGN KEY ', constraint_name)
 | 
						|
FROM information_schema.key_column_usage
 | 
						|
WHERE constraint_schema = DATABASE()
 | 
						|
  AND table_name = 'reminders'
 | 
						|
  AND column_name = 'set_by';
 | 
						|
PREPARE reminders_stmt FROM @reminders_query;
 | 
						|
EXECUTE reminders_stmt;
 | 
						|
-- Drop old column
 | 
						|
ALTER TABLE reminders
 | 
						|
    DROP COLUMN set_by;
 | 
						|
ALTER TABLE reminders RENAME COLUMN set_by_new TO set_by;
 | 
						|
 | 
						|
-- Swap the tables.
 | 
						|
-- Keep the old table for now
 | 
						|
RENAME TABLE users TO users_old;
 | 
						|
RENAME TABLE users_new TO users;
 | 
						|
 | 
						|
SET FOREIGN_KEY_CHECKS = 1;
 |