diff options
| author | Shauren <shauren.trinity@gmail.com> | 2024-10-03 12:22:22 +0200 |
|---|---|---|
| committer | Ovahlord <dreadkiller@gmx.de> | 2024-10-03 15:06:58 +0200 |
| commit | 01e3220f8969818b5b0ee38bf27316cb8a5bfb5f (patch) | |
| tree | 71e84ab9e3379d74860bc7079c6cf4c4c8576a59 /sql | |
| parent | 77124dc57e6b01632340013fdc3c1fb8ce92165e (diff) | |
Core/Players: Prevent creation of characters with duplicate names
Closes #30299
(cherry picked from commit 49ab2bbe3883749594fe92a752e1d618c625d1b6)
Diffstat (limited to 'sql')
| -rw-r--r-- | sql/base/characters_database.sql | 9 | ||||
| -rw-r--r-- | sql/updates/characters/cata_classic/2024_10_03_00_characters.sql | 29 |
2 files changed, 34 insertions, 4 deletions
diff --git a/sql/base/characters_database.sql b/sql/base/characters_database.sql index b156dc50965..f90bcca4bec 100644 --- a/sql/base/characters_database.sql +++ b/sql/base/characters_database.sql @@ -1692,7 +1692,7 @@ DROP TABLE IF EXISTS `characters`; CREATE TABLE `characters` ( `guid` bigint 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, `slot` tinyint unsigned NOT NULL DEFAULT '0', `race` tinyint unsigned NOT NULL DEFAULT '0', `class` tinyint unsigned NOT NULL DEFAULT '0', @@ -1777,9 +1777,9 @@ CREATE TABLE `characters` ( `personalTabardBorderColor` int NOT NULL DEFAULT '-1', `personalTabardBackgroundColor` int NOT NULL DEFAULT '-1', 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 */; @@ -3380,7 +3380,8 @@ INSERT INTO `updates` VALUES ('2024_07_27_00_characters.sql','912ADCAC4948C75386387251D6FAEFB841574606','RELEASED','2024-07-27 01:03:05',0), ('2024_07_28_00_characters.sql','22C94D231C155686691780B65C12FCC2B4C3A6AA','RELEASED','2024-07-28 00:59:04',0), ('2024_08_27_00_characters_2024_08_26_00_characters.sql','68EEBE1D639D59B24F5121008C2D103CA67FFC9A','RELEASED','2024-08-27 17:15:49',0), -('2024_09_01_00_characters.sql','B921A034AFAB2BFFF3EDA6EE9AB3152EFE503734','RELEASED','2024-09-01 20:45:47',0); +('2024_09_01_00_characters.sql','B921A034AFAB2BFFF3EDA6EE9AB3152EFE503734','RELEASED','2024-09-01 20:45:47',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/cata_classic/2024_10_03_00_characters.sql b/sql/updates/characters/cata_classic/2024_10_03_00_characters.sql new file mode 100644 index 00000000000..7b5a6fcf357 --- /dev/null +++ b/sql/updates/characters/cata_classic/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); |
