From 3acb25c50cddb6f2b00bf8d8a48b5d47b1e7b4f7 Mon Sep 17 00:00:00 2001 From: Shauren Date: Thu, 3 Oct 2024 14:41:02 +0200 Subject: Core/Players: Prevent creation of characters with duplicate names Closes #30299 (cherry picked from commit 49ab2bbe3883749594fe92a752e1d618c625d1b6) --- sql/base/characters_database.sql | 9 ++++--- .../characters/3.3.5/2024_10_03_00_characters.sql | 29 ++++++++++++++++++++++ 2 files changed, 34 insertions(+), 4 deletions(-) create mode 100644 sql/updates/characters/3.3.5/2024_10_03_00_characters.sql (limited to 'sql') diff --git a/sql/base/characters_database.sql b/sql/base/characters_database.sql index 5612d8f3b89..12faae6da4d 100644 --- a/sql/base/characters_database.sql +++ b/sql/base/characters_database.sql @@ -1340,7 +1340,7 @@ DROP TABLE IF EXISTS `characters`; CREATE TABLE `characters` ( `guid` int unsigned NOT NULL DEFAULT '0' COMMENT 'Global Unique Identifier', `account` int unsigned NOT NULL DEFAULT '0' COMMENT 'Account Identifier', - `name` varchar(12) CHARACTER SET utf8mb4 COLLATE utf8mb4_bin NOT NULL, + `name` varchar(12) CHARACTER SET utf8mb4 COLLATE utf8mb4_bin DEFAULT NULL, `race` tinyint unsigned NOT NULL DEFAULT '0', `class` tinyint unsigned NOT NULL DEFAULT '0', `gender` tinyint unsigned NOT NULL DEFAULT '0', @@ -1415,9 +1415,9 @@ CREATE TABLE `characters` ( `deleteInfos_Name` varchar(12) CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci DEFAULT NULL, `deleteDate` int unsigned DEFAULT NULL, PRIMARY KEY (`guid`), + UNIQUE KEY `idx_name` (`name`), KEY `idx_account` (`account`), - KEY `idx_online` (`online`), - KEY `idx_name` (`name`) + KEY `idx_online` (`online`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='Player System'; /*!40101 SET character_set_client = @saved_cs_client */; @@ -2686,7 +2686,8 @@ INSERT INTO `updates` VALUES ('2024_01_21_00_characters.sql','4D27D8DAC9F78795DB6938B54F32502EF8D8AAE6','ARCHIVED','2024-01-21 11:38:22',0), ('2024_02_05_00_characters.sql','1777CBCA822AD85777DA4A390DF7AAF41AF68EBD','ARCHIVED','2024-02-05 12:17:19',0), ('2024_04_10_00_characters.sql','E0D6E19ACE6759332402FA27C23B0F7745C49742','ARCHIVED','2024-04-10 16:07:02',0), -('2024_08_17_00_characters.sql','08705FBCB8504E8B1009FDAF955F56D734FAD782','ARCHIVED','2024-08-17 22:26:12',0); +('2024_08_17_00_characters.sql','08705FBCB8504E8B1009FDAF955F56D734FAD782','ARCHIVED','2024-08-17 22:26:12',0), +('2024_10_03_00_characters.sql','408249A6992999A36EB94089D184972E8E0767A3','RELEASED','2024-10-03 11:10:18',0); /*!40000 ALTER TABLE `updates` ENABLE KEYS */; UNLOCK TABLES; diff --git a/sql/updates/characters/3.3.5/2024_10_03_00_characters.sql b/sql/updates/characters/3.3.5/2024_10_03_00_characters.sql new file mode 100644 index 00000000000..7b5a6fcf357 --- /dev/null +++ b/sql/updates/characters/3.3.5/2024_10_03_00_characters.sql @@ -0,0 +1,29 @@ +-- append guid as hex to characters who have duplicate names in database except the one with lowest guid (assumed to have been created first) +-- and flag them for rename +CREATE TEMPORARY TABLE `characters_to_rename` SELECT + c2.`guid` + FROM + ( + SELECT + c1.`name` AS `name`, + MIN(c1.`guid`) AS originalGuid + FROM + `characters` c1 + WHERE + LENGTH(c1.`name`) > 0 + GROUP BY + 1 + HAVING + COUNT(*) > 1 + ) c3 + INNER JOIN `characters` c2 ON c3.`name` = c2.`name` + WHERE + c2.guid <> c3.originalGuid; + +UPDATE `characters` SET `name` = CONCAT(SUBSTRING(`name` FROM 1 FOR 12 - LENGTH(CONV(`guid`, 10, 16))), CONV(`guid`, 10, 16)), `at_login` = `at_login` | 1 WHERE `guid` IN (SELECT `guid` FROM `characters_to_rename`); + +-- recreate name index with unique constraint +ALTER TABLE `characters` DROP INDEX `idx_name`; +ALTER TABLE `characters` MODIFY COLUMN `name` varchar(12) CHARACTER SET utf8mb4 COLLATE utf8mb4_bin NULL AFTER `account`; +UPDATE `characters` SET `name` = NULL WHERE `name` = ''; +ALTER TABLE `characters` ADD UNIQUE INDEX `idx_name` (`name` ASC); -- cgit v1.2.3