-
Notifications
You must be signed in to change notification settings - Fork 18
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
- Loading branch information
Showing
1 changed file
with
42 additions
and
0 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,42 @@ | ||
DROP TABLE IF EXISTS `service_links`; | ||
|
||
CREATE TABLE `service_links` ( | ||
`id` CHAR(36) CHARACTER SET ascii NOT NULL, | ||
`user_id` mediumint(8) unsigned COMMENT 'To be set to null if account is deleted', | ||
`type` enum('STEAM', 'GOG', 'DISCORD', 'PATREON') COLLATE utf8mb4_unicode_ci NOT NULL COMMENT 'The service that this service id links to.', | ||
`service_id` varchar(100) COMMENT 'To be set to null if account is deleted unless ownership is true', | ||
`public` boolean, | ||
`ownership` boolean COMMENT 'If true, this link confirms that the user owns FAForever. If true the link must never be deleted even if the linked account gets deleted. In this case we keep a dangling link so the id cannot be reused', | ||
PRIMARY KEY (id), | ||
UNIQUE KEY `unique_service_id` (`type`, `service_id`), | ||
CONSTRAINT `user_ibfk_1` FOREIGN KEY (`user_id`) REFERENCES `login` (`id`) ON DELETE RESTRICT ON UPDATE CASCADE | ||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='table representing the links to various services'; | ||
|
||
# MIGRATION SCRIPT | ||
# drop table if exists temp_id_holder; | ||
# | ||
# create temporary table temp_id_holder as | ||
# select * from login WHERE `steamid` IS NOT NULL or `gog_id` IS NOT NULL | ||
# order by RAND(); | ||
# | ||
# INSERT into `service_links` (`id`, `user_id`, `type`, `service_id`, `ownership`, `public`) | ||
# SELECT UUID(), `id`, "STEAM", `steamid`, true, false | ||
# FROM `temp_id_holder` WHERE `steamid` IS NOT NULL and `login` not LIKE "anonymized_%" and `email` not LIKE "anonymized_%" and password != "anonymized" | ||
# ON DUPLICATE KEY UPDATE `user_id`=`user_id`; | ||
# | ||
# INSERT into `service_links` (`id`, `type`, `service_id`, `ownership`, `public`) | ||
# SELECT UUID(), "STEAM", `steamid`, true, false | ||
# FROM `temp_id_holder` WHERE `steamid` IS NOT NULL and (`login` LIKE "anonymized_%" or `email` LIKE "anonymized_%" or password = "anonymized") | ||
# ON DUPLICATE KEY UPDATE `user_id`=`user_id`; | ||
# | ||
# INSERT into `service_links` (`id`, `user_id`, `type`, `service_id`, `ownership`, `public`) | ||
# SELECT UUID(), `id`, "GOG", `gog_id`, true, false | ||
# FROM `temp_id_holder` WHERE `gog_id` IS NOT NULL and `login` not LIKE "anonymized_%" and `email` not LIKE "anonymized_%" and password != "anonymized" | ||
# ON DUPLICATE KEY UPDATE `user_id`=`user_id`; | ||
# | ||
# INSERT into `service_links` (`id`, `type`, `service_id`, `ownership`, `public`) | ||
# SELECT UUID(), "GOG", `gog_id`, true, false | ||
# FROM `temp_id_holder` WHERE `gog_id` IS NOT NULL and (`login` LIKE "anonymized_%" or `email` LIKE "anonymized_%" or password = "anonymized") | ||
# ON DUPLICATE KEY UPDATE `user_id`=`user_id`; | ||
# | ||
# drop table if exists temp_id_holder; |