convert_guild_tables.sql 3.4 KB

12345678910111213141516171819202122232425262728293031323334353637383940414243444546474849505152535455565758596061626364656667686970717273747576777879808182
  1. ###################################################################################################
  2. # This one is also necessary, since foreign keys may only reference
  3. # InnoDB tables.
  4. ALTER TABLE `char` TYPE=InnoDB;
  5. ###################################################################################################
  6. # Add the new guild column char_id and populate it with Guild Master ids
  7. # Note that the auto-fill is case sensitive!
  8. ALTER TABLE `guild` ADD COLUMN `char_id` int(11) NOT NULL DEFAULT '10000' AFTER `name`;
  9. UPDATE `guild`,`char` SET `guild`.`char_id`=`char`.`char_id` WHERE `guild`.`master` = `char`.`name`;
  10. ###################################################################################################
  11. # Now we go on altering stuff - dropping old keys (just in case),
  12. # converting table types, and then creating new keys.
  13. ALTER TABLE guild DROP PRIMARY KEY;
  14. ALTER TABLE guild TYPE=InnoDB;
  15. ALTER TABLE guild
  16. ADD PRIMARY KEY (guild_id,char_id),
  17. MODIFY COLUMN `guild_id` INTEGER NOT NULL AUTO_INCREMENT, AUTO_INCREMENT = 10000,
  18. ADD KEY char_id (char_id),
  19. ADD UNIQUE KEY guild_id (guild_id),
  20. ADD CONSTRAINT `guild_ibfk_1` FOREIGN KEY (`char_id`) REFERENCES `char`
  21. (`char_id`) ON DELETE CASCADE;
  22. ALTER TABLE guild_alliance DROP INDEX `guild_id`;
  23. ALTER TABLE guild_alliance TYPE=InnoDB;
  24. ALTER TABLE guild_alliance
  25. ADD PRIMARY KEY (guild_id,alliance_id),
  26. ADD KEY alliance_id (alliance_id),
  27. ADD CONSTRAINT `guild_alliance_ibfk_1` FOREIGN KEY (`guild_id`)
  28. REFERENCES `guild` (`guild_id`) ON DELETE CASCADE,
  29. ADD CONSTRAINT `guild_alliance_ibfk_2` FOREIGN KEY (`alliance_id`)
  30. REFERENCES `guild` (`guild_id`) ON DELETE CASCADE;
  31. ALTER TABLE guild_castle DROP PRIMARY KEY, DROP INDEX `guild_id`;
  32. ALTER TABLE guild_castle TYPE=InnoDB;
  33. ALTER TABLE guild_castle
  34. ADD PRIMARY KEY (castle_id);
  35. ALTER TABLE guild_expulsion DROP INDEX `guild_id`;
  36. ALTER TABLE guild_expulsion TYPE=InnoDB;
  37. ALTER TABLE guild_expulsion
  38. ADD PRIMARY KEY (guild_id,name),
  39. ADD CONSTRAINT `guild_expulsion_ibfk_1` FOREIGN KEY (`guild_id`)
  40. REFERENCES `guild` (`guild_id`) ON DELETE CASCADE;
  41. ALTER TABLE guild_member DROP INDEX `guild_id`, DROP INDEX `account_id`;
  42. ALTER TABLE guild_member TYPE=InnoDB;
  43. ALTER TABLE guild_member DROP INDEX `char_id`;
  44. ALTER TABLE guild_member
  45. ADD PRIMARY KEY (guild_id,char_id),
  46. ADD KEY char_id (char_id),
  47. ADD CONSTRAINT `guild_member_ibfk_1` FOREIGN KEY (`guild_id`)
  48. REFERENCES `guild` (`guild_id`) ON DELETE CASCADE,
  49. ADD CONSTRAINT `guild_member_ibfk_2` FOREIGN KEY (`char_id`)
  50. REFERENCES `char` (`char_id`) ON DELETE CASCADE;
  51. ALTER TABLE guild_position DROP INDEX `guild_id`;
  52. ALTER TABLE guild_position TYPE=InnoDB;
  53. ALTER TABLE guild_position
  54. ADD PRIMARY KEY (guild_id,position),
  55. ADD KEY guild_id (guild_id),
  56. ADD CONSTRAINT `guild_position_ibfk_1` FOREIGN KEY (`guild_id`)
  57. REFERENCES `guild` (`guild_id`) ON DELETE CASCADE;
  58. ALTER TABLE guild_skill DROP INDEX `guild_id`;
  59. ALTER TABLE guild_skill TYPE=InnoDB;
  60. ALTER TABLE guild_skill
  61. ADD PRIMARY KEY (guild_id,id),
  62. ADD CONSTRAINT `guild_skill_ibfk_1` FOREIGN KEY (`guild_id`)
  63. REFERENCES `guild` (`guild_id`) ON DELETE CASCADE;
  64. ALTER TABLE guild_storage DROP INDEX `guild_id`;
  65. ALTER TABLE guild_storage TYPE=InnoDB;
  66. ALTER TABLE guild_storage
  67. ADD KEY guild_id (guild_id),
  68. ADD CONSTRAINT `guild_storage_ibfk_1` FOREIGN KEY (`guild_id`)
  69. REFERENCES `guild` (`guild_id`) ON DELETE CASCADE;