Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Migrate prod database #992

Open
wants to merge 7 commits into
base: master
Choose a base branch
from
Open
Show file tree
Hide file tree
Changes from 6 commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
15 changes: 15 additions & 0 deletions db/migrations/1900000000__preprod-changes.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,15 @@
-- +migrate Up

ALTER TABLE `groups_login_prefixes` DROP COLUMN `idUserCreator`;
Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

This is the line that makes the migration fail

ALTER TABLE `items_items` DROP COLUMN `iWeight`;

ALTER TABLE `groups` DROP KEY `sPassword`;
ALTER TABLE `groups` DROP KEY `sType`;
ALTER TABLE `groups` DROP KEY `sTextId`;
ALTER TABLE `groups_groups` DROP KEY `idUserInviting`;
ALTER TABLE `history_groups_groups` DROP KEY `idGroupParent`;
ALTER TABLE `history_groups_groups` DROP KEY `idGroupChild`;
ALTER TABLE `history_groups_groups` DROP KEY `idUserInviting`;
ALTER TABLE `users_items` DROP KEY `UserAttempt`;

-- +migrate Down
17 changes: 17 additions & 0 deletions db/migrations/1908210505_add_unique_index_sPassword_on_groups.sql
Original file line number Diff line number Diff line change
@@ -1,5 +1,22 @@
-- +migrate Up
UPDATE `groups` SET `sPassword` = NULL WHERE `sPassword` = '';

# Deduplicate groups.sPassword: appends a suffix to make all sPassword unique.
UPDATE `groups`
JOIN (
SELECT `ID`, ROW_NUMBER() OVER (PARTITION BY `groups`.`sPassword` ORDER BY `ID`) AS `order`
FROM `groups`
JOIN (
SELECT `ID`, `sPassword` FROM `groups` AS `groups1`
WHERE EXISTS(
SELECT `ID` from `groups` AS `groups2`
WHERE `groups1`.`sPassword`=`groups2`.`sPassword` AND `groups1`.`ID` > `groups2`.`ID`
)
GROUP BY `ID`
) AS `duplicates` USING (`ID`)
) AS `orders` USING (`ID`)
SET `groups`.`sPassword` = CONCAT(`groups`.`sPassword`, '@dup', `orders`.`order`);

ALTER TABLE `groups` ADD UNIQUE INDEX `sPassword` (`sPassword`);

-- +migrate Down
Expand Down
4 changes: 2 additions & 2 deletions db/migrations/1909101934_add_comments_groups_groups_table.sql
Original file line number Diff line number Diff line change
Expand Up @@ -3,13 +3,13 @@ ALTER TABLE `groups_groups`
COMMENT 'Parent-child (N-N) relationships between groups (acyclic graph). It includes potential relationships such as invitations or requests to join groups, as well as past relationships.',
MODIFY COLUMN `iChildOrder` int(11) NOT NULL DEFAULT '0' COMMENT 'Position of this child among its siblings.',
MODIFY COLUMN `sRole` enum('manager','owner','member','observer') NOT NULL DEFAULT 'member' COMMENT 'Role that the child has relative to the parent.',
MODIFY COLUMN `idUserInviting` int(11) DEFAULT NULL COMMENT 'User (one of the admins of the parent group) who initiated the invitation or accepted the request',
MODIFY COLUMN `idUserInviting` int(20) DEFAULT NULL COMMENT 'User (one of the admins of the parent group) who initiated the invitation or accepted the request',
MODIFY COLUMN `sStatusDate` datetime DEFAULT NULL COMMENT 'When was the type last Changed.';

-- +migrate Down
ALTER TABLE `groups_groups`
COMMENT '',
MODIFY COLUMN `iChildOrder` int(11) NOT NULL DEFAULT '0' COMMENT '',
MODIFY COLUMN `sRole` enum('manager','owner','member','observer') NOT NULL DEFAULT 'member' COMMENT '',
MODIFY COLUMN `idUserInviting` int(11) DEFAULT NULL COMMENT '',
MODIFY COLUMN `idUserInviting` int(20) DEFAULT NULL COMMENT '',
MODIFY COLUMN `sStatusDate` datetime DEFAULT NULL COMMENT '';
3 changes: 3 additions & 0 deletions db/migrations/1910250534_get_rid_of_user_id_everywhere.sql
Original file line number Diff line number Diff line change
Expand Up @@ -74,6 +74,9 @@ ALTER TABLE `threads`
DROP COLUMN `creator_user_id`;

UPDATE `users_answers` LEFT JOIN `users` ON `users`.`id` = `users_answers`.`user_id` SET `users_answers`.`user_id` = `users`.`group_id`;

DELETE FROM users_answers ua WHERE ua.user_id NOT IN (SELECT group_id FROM users);

ALTER TABLE `users_answers`
ADD CONSTRAINT `fk_users_answers_user_id_users_group_id` FOREIGN KEY (`user_id`) REFERENCES `users`(`group_id`) ON DELETE CASCADE,
DROP COLUMN `grader_user_id`;
Expand Down
4 changes: 4 additions & 0 deletions db/migrations/2002040752_clean_platforms.sql
Original file line number Diff line number Diff line change
Expand Up @@ -4,6 +4,10 @@ ALTER TABLE `platforms`

UPDATE `platforms` SET `public_key` = NULL WHERE NOT uses_tokens OR `public_key` = '';

UPDATE `platforms` p1
JOIN (SELECT id, `priority`*10 + row_number() OVER (PARTITION BY `priority` ORDER BY `priority`) -1 as `new_priority` FROM platforms) p2 ON p1.id = p2.id
SET p1.`priority` = p2.`new_priority`;

ALTER TABLE `platforms`
DROP COLUMN `uses_tokens`,
ADD UNIQUE KEY `priority` (`priority` DESC),
Expand Down
2 changes: 1 addition & 1 deletion db/migrations/2002051347_add_groups_type_session.sql
Original file line number Diff line number Diff line change
Expand Up @@ -21,7 +21,7 @@ ALTER TABLE `groups`
ADD COLUMN `address_country` VARCHAR(255) DEFAULT NULL COMMENT 'For sessions or schools',
ADD COLUMN `expected_start` DATETIME DEFAULT NULL COMMENT 'For sessions, time at which the session is expected to start';

UPDATE `groups` SET `activity_id` = REVERSE(SUBSTRING_INDEX(REVERSE(redirect_path), '/', 1))
UPDATE `groups` SET `activity_id` = REVERSE(SUBSTRING_INDEX(REVERSE(REVERSE(SUBSTRING_INDEX(REVERSE(redirect_path), '/', 1))), '-', 1))
WHERE `redirect_path` IS NOT NULL AND `redirect_path` != '';

ALTER TABLE `groups` DROP COLUMN `redirect_path`;
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -21,7 +21,7 @@ CREATE TABLE `user_batches` (
`creator_id` BIGINT(20) DEFAULT NULL,
`created_at` DATETIME NOT NULL DEFAULT NOW(),
PRIMARY KEY (`group_prefix`, `custom_prefix`),
CONSTRAINT `ck_user_batches_custom_prefix` CHECK (BINARY `custom_prefix` REGEXP '^[a-z0-9-]+$'),
CONSTRAINT `ck_user_batches_custom_prefix` CHECK (CAST(`custom_prefix` AS BINARY) REGEXP BINARY '^[a-z0-9-]+$'),
CONSTRAINT `fk_user_batches_group_prefix_user_batch_prefixes_group_prefix`
FOREIGN KEY (`group_prefix`) REFERENCES `user_batch_prefixes`(`group_prefix`) ON DELETE RESTRICT,
CONSTRAINT `fk_user_batches_creator_id_users_group_id`
Expand Down
20 changes: 15 additions & 5 deletions db/schema/schema.sql
Original file line number Diff line number Diff line change
Expand Up @@ -221,7 +221,10 @@ CREATE TABLE `groups` (
`lockUserDeletionDate` date DEFAULT NULL,
PRIMARY KEY (`ID`),
KEY `iVersion` (`iVersion`),
KEY `bAncestorsComputed` (`sAncestorsComputationState`)
KEY `bAncestorsComputed` (`sAncestorsComputationState`),
KEY `sPassword` (`sPassword`),
KEY `sType` (`sType`),
KEY `sTextId` (`sTextId`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8;
SET character_set_client = @saved_cs_client;

Expand Down Expand Up @@ -535,14 +538,15 @@ CREATE TABLE `groups_groups` (
`iChildOrder` int(11) NOT NULL DEFAULT '0',
`sType` enum('invitationSent','requestSent','invitationAccepted','requestAccepted','invitationRefused','requestRefused','removed','left','direct') NOT NULL DEFAULT 'direct',
`sRole` enum('manager','owner','member','observer') NOT NULL DEFAULT 'member',
`idUserInviting` int(11) DEFAULT NULL,
`idUserInviting` int(20) DEFAULT NULL,
`sStatusDate` datetime DEFAULT NULL,
`iVersion` bigint(20) NOT NULL,
PRIMARY KEY (`ID`),
UNIQUE KEY `parentchild` (`idGroupParent`,`idGroupChild`),
KEY `iVersion` (`iVersion`),
KEY `idGroupChild` (`idGroupChild`),
KEY `idGroupParent` (`idGroupParent`)
KEY `idGroupParent` (`idGroupParent`),
KEY `idUserInviting` (`idUserInviting`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8;
SET character_set_client = @saved_cs_client;

Expand Down Expand Up @@ -775,6 +779,7 @@ SET @saved_cs_client = @@character_set_client;
CREATE TABLE `groups_login_prefixes` (
`ID` bigint(20) NOT NULL AUTO_INCREMENT,
`idGroup` bigint(20) NOT NULL,
`idUserCreator` BIGINT(20) NOT NULL,
`prefix` varchar(100) CHARACTER SET utf8 COLLATE utf8_unicode_ci NOT NULL,
`iVersion` bigint(20) NOT NULL,
PRIMARY KEY (`ID`),
Expand Down Expand Up @@ -1097,6 +1102,9 @@ CREATE TABLE `history_groups_groups` (
KEY `iVersion` (`iVersion`),
KEY `ID` (`ID`),
KEY `iNextVersion` (`iNextVersion`),
KEY `idGroupParent` (`idGroupParent`),
KEY `idGroupChild` (`idGroupChild`),
KEY `idUserInviting` (`idUserInviting`),
KEY `bDeleted` (`bDeleted`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8;
SET character_set_client = @saved_cs_client;
Expand Down Expand Up @@ -1201,7 +1209,7 @@ SET @saved_cs_client = @@character_set_client;
CREATE TABLE `history_items` (
`historyID` bigint(20) NOT NULL AUTO_INCREMENT,
`ID` bigint(20) NOT NULL,
`sUrl` varchar(200) DEFAULT NULL,
`sUrl` varchar(500) DEFAULT NULL,
`sOptions` TEXT NOT NULL,
`idPlatform` int(11) DEFAULT NULL,
`sTextId` varchar(200) DEFAULT NULL,
Expand Down Expand Up @@ -1682,7 +1690,7 @@ SET @saved_cs_client = @@character_set_client;
SET character_set_client = utf8mb4;
CREATE TABLE `items` (
`ID` bigint(20) NOT NULL,
`sUrl` varchar(200) DEFAULT NULL,
`sUrl` varchar(500) DEFAULT NULL,
`sOptions` TEXT NOT NULL,
`idPlatform` int(11) DEFAULT NULL,
`sTextId` varchar(200) DEFAULT NULL,
Expand Down Expand Up @@ -1913,6 +1921,7 @@ CREATE TABLE `items_items` (
`sCategory` enum('Undefined','Discovery','Application','Validation','Challenge') NOT NULL DEFAULT 'Undefined',
`bAlwaysVisible` tinyint(1) NOT NULL DEFAULT '0',
`bAccessRestricted` tinyint(1) NOT NULL DEFAULT '1',
`iWeight` INT NOT NULL DEFAULT '1',
`iDifficulty` int(11) NOT NULL,
`iVersion` bigint(20) NOT NULL,
PRIMARY KEY (`ID`),
Expand Down Expand Up @@ -2709,6 +2718,7 @@ CREATE TABLE `users_items` (
`bPlatformDataRemoved` tinyint(4) NOT NULL DEFAULT '0',
PRIMARY KEY (`ID`),
UNIQUE KEY `UserItem` (`idUser`,`idItem`),
KEY `UserAttempt` (`idUser`,`idAttemptActive`),
KEY `iVersion` (`iVersion`),
KEY `sAncestorsComputationState` (`sAncestorsComputationState`),
KEY `idItem` (`idItem`),
Expand Down